Add SPLIT PARTITION/MERGE PARTITIONS commands
Hi, hackers!
There are not many commands in PostgreSQL for working with partitioned
tables. This is an obstacle to their widespread use.
Adding SPLIT PARTITION/MERGE PARTITIONS operations can make easier to
use partitioned tables in PostgreSQL.
(This is especially important when migrating projects from ORACLE DBMS.)
SPLIT PARTITION/MERGE PARTITIONS commands are supported for range
partitioning (BY RANGE) and for list partitioning (BY LIST).
For hash partitioning (BY HASH) these operations are not supported.
=================
1 SPLIT PARTITION
=================
Command for split a single partition.
1.1 Syntax
----------
ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO
(PARTITION <partition_name1> { FOR VALUES <partition_bound_spec> |
DEFAULT },
[ ... ]
PARTITION <partition_nameN> { FOR VALUES <partition_bound_spec> |
DEFAULT })
<partition_bound_spec>:
IN ( <partition_bound_expr> [, ...] ) |
FROM ( { <partition_bound_expr> | MINVALUE | MAXVALUE } [, ...] )
TO ( { <partition_bound_expr> | MINVALUE | MAXVALUE } [, ...] )
1.2 Rules
---------
1.2.1 The <partition_name> partition should be split into two (or more)
partitions.
1.2.2 New partitions should have different names (with existing
partitions too).
1.2.3 Bounds of new partitions should not overlap with new and existing
partitions.
1.2.4 In case split partition is DEFAULT partition, one of new
partitions should be DEFAULT.
1.2.5 In case new partitions or existing partitions contains DEFAULT
partition, new partitions <partition_name1>...<partition_nameN> can have
any bounds inside split partition bound (can be spaces between
partitions bounds).
1.2.6 In case partitioned table does not have DEFAULT partition, DEFAULT
partition can be defined as one of new partition.
1.2.7 In case new partitions not contains DEFAULT partition and
partitioned table does not have DEFAULT partition the following should
be true: sum bounds of new partitions
<partition_name1>...<partition_nameN> should be equal to bound of split
partition <partition_name>.
1.2.8 One of the new partitions <partition_name1>-<partition_nameN> can
have the same name as split partition <partition_name> (this is suitable
in case splitting a DEFAULT partition: we split it, but after splitting
we have a partition with the same name).
1.2.9 Only simple (non-partitioned) partitions can be split.
1.3 Examples
------------
1.3.1 Example for range partitioning (BY RANGE):
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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES
FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO
('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO
('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO
('2022-05-01'));
1.3.2 Example for list partitioning (BY LIST):
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_all PARTITION OF sales_list FOR VALUES IN ('Moscow',
'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk',
'Volgograd', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk',
'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan',
'Volgograd'));
1.4 ToDo:
---------
1.4.1 Possibility to specify tablespace for each of the new partitions
(currently new partitions are created in the same tablespace as split
partition).
1.4.2 Possibility to use CONCURRENTLY mode that allows (during the SPLIT
operation) not blocking partitions that are not splitting.
==================
2 MERGE PARTITIONS
==================
Command for merge several partitions into one partition.
2.1 Syntax
----------
ALTER TABLE <name> MERGE PARTITIONS (<partition_name1>,
<partition_name2>[, ...]) INTO <new_partition_name>;
2.2 Rules
---------
2.2.1 The number of partitions that are merged into the new partition
<new_partition_name> should be at least two.
2.2.2
If DEFAULT partition is not in the list of partitions <partition_name1>,
<partition_name2>[, ...]:
* for range partitioning (BY RANGE) is necessary that the ranges of
the partitions <partition_name1>, <partition_name2>[, ...] can be merged
into one range without spaces and overlaps (otherwise an error will be
generated).
The combined range will be the range for the partition
<new_partition_name>.
* for list partitioning (BY LIST) the values lists of all partitions
<partition_name1>, <partition_name2>[, ...] are combined and form a list
of values of partition <new_partition_name>.
If DEFAULT partition is in the list of partitions <partition_name1>,
<partition_name2>[, ...]:
* the partition <new_partition_name> will be the DEFAULT partition;
* for both partitioning types (BY RANGE, BY LIST) the ranges and
lists of values of the merged partitions can be any.
2.2.3 The new partition <new_partition_name> can have the same name as
one of the merged partitions.
2.2.4 Only simple (non-partitioned) partitions can be merged.
2.3 Examples
------------
2.3.1 Example for range partitioning (BY RANGE):
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;
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022,
sales_apr2022) INTO sales_feb_mar_apr2022;
2.3.2 Example for list partitioning (BY LIST):
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;
ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east,
sales_central) INTO sales_all;
2.4 ToDo:
---------
2.4.1 Possibility to specify tablespace for the new partition (currently
new partition is created in the same tablespace as partitioned table).
2.4.2 Possibility to use CONCURRENTLY mode that allows (during the MERGE
operation) not blocking partitions that are not merging.
2.4.3 New syntax for ALTER TABLE ... MERGE PARTITIONS command for range
partitioning (BY RANGE):
ALTER TABLE <name> MERGE PARTITIONS <partition_name1> TO
<partition_name2> INTO <new_partition_name>;
This command can merge all partitions between <partition_name1> and
<partition_name2> into new partition <new_partition_name>.
This can be useful for this example cases: need to merge all one-month
partitions into a year partition or need to merge all one-day partitions
into a month partition.
Your opinions are very much welcome!
--
With best regards,
Dmitry Koval.
Attachments:
v1-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v1-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2de0ebacec3..194a720388a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -634,6 +634,11 @@ static List *GetParentedForeignKeyRefs(Relation partition);
static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4383,6 +4388,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4803,6 +4816,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5208,6 +5231,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6195,6 +6234,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17649,6 +17692,35 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartTable: attach new partition to partitioned table
+ *
+ * rel: partitioned relation;
+ * attachRel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartTable(List **wqueue, Relation rel, Relation attachRel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachRel, rel);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachRel, rel, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17841,23 +17913,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. */
+ attachPartTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -19288,3 +19345,663 @@ GetAttributeCompression(Oid atttypid, char *compression)
return cmethod;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartContext;
+
+
+/*
+ * createSplitPartContext: create context for partition and fill it
+ */
+static SplitPartContext *
+createSplitPartContext(Relation partRel)
+{
+ SplitPartContext *pc;
+
+ pc = (SplitPartContext *) palloc0(sizeof(SplitPartContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartContext: delete context for partition
+ */
+static void
+deleteSplitPartContext(SplitPartContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition contect into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ pc = createSplitPartContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = pc;
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartContext((SplitPartContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartTable(NULL, rel, newPartRel, sps->bound);
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop splitted partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ if (!strcmp(name->relname, cmd->name->relname))
+ /* 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.
+ */
+ attachPartTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Unlock and drop merged partitions. */
+ foreach(listptr, partContexts)
+ {
+ ObjectAddress object;
+ MergedPartContext *pc = (MergedPartContext *) lfirst(listptr);
+
+ /* Unlock partition. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ pfree(pc);
+ }
+
+ /* Rename new partition if it is need. */
+ 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/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 51d630fa892..416ad65d528 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -5350,6 +5350,17 @@ _copyPartitionRangeDatum(const PartitionRangeDatum *from)
return newnode;
}
+static SinglePartitionSpec *
+_copySinglePartitionSpec(const SinglePartitionSpec *from)
+{
+ SinglePartitionSpec *newnode = makeNode(SinglePartitionSpec);
+
+ COPY_NODE_FIELD(name);
+ COPY_NODE_FIELD(bound);
+
+ return newnode;
+}
+
static PartitionCmd *
_copyPartitionCmd(const PartitionCmd *from)
{
@@ -5357,6 +5368,7 @@ _copyPartitionCmd(const PartitionCmd *from)
COPY_NODE_FIELD(name);
COPY_NODE_FIELD(bound);
+ COPY_NODE_FIELD(partlist);
COPY_SCALAR_FIELD(concurrent);
return newnode;
@@ -6560,6 +6572,9 @@ copyObjectImpl(const void *from)
case T_PartitionRangeDatum:
retval = _copyPartitionRangeDatum(from);
break;
+ case T_SinglePartitionSpec:
+ retval = _copySinglePartitionSpec(from);
+ break;
case T_PartitionCmd:
retval = _copyPartitionCmd(from);
break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index e747e1667d0..7e217f3e2a9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -3443,11 +3443,21 @@ _equalPartitionRangeDatum(const PartitionRangeDatum *a, const PartitionRangeDatu
return true;
}
+static bool
+_equalSinglePartitionSpec(const SinglePartitionSpec *a, const SinglePartitionSpec *b)
+{
+ COMPARE_NODE_FIELD(name);
+ COMPARE_NODE_FIELD(bound);
+
+ return true;
+}
+
static bool
_equalPartitionCmd(const PartitionCmd *a, const PartitionCmd *b)
{
COMPARE_NODE_FIELD(name);
COMPARE_NODE_FIELD(bound);
+ COMPARE_NODE_FIELD(partlist);
COMPARE_SCALAR_FIELD(concurrent);
return true;
@@ -4363,6 +4373,9 @@ equal(const void *a, const void *b)
case T_PartitionRangeDatum:
retval = _equalPartitionRangeDatum(a, b);
break;
+ case T_SinglePartitionSpec:
+ retval = _equalSinglePartitionSpec(a, b);
+ break;
case T_PartitionCmd:
retval = _equalPartitionCmd(a, b);
break;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 989db0dbece..d860f9021a1 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17862,6 +17914,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17929,6 +17982,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18480,6 +18534,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18559,6 +18614,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1a64a522798..28482597feb 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3273,6 +3275,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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 (!strcmp(name->relname, name2->relname))
+ 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
@@ -3536,7 +3648,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3544,6 +3656,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3935,13 +4065,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3950,9 +4080,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3960,7 +4090,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6b35111ebb6..9a10411f7c6 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4998,3 +4998,843 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums && found; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ found = false;
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be splitted")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (!strcmp(sps->name->relname, sps2->name->relname))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c3937a60fd3..1622c4f7c32 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12869,3 +12869,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index b3b407579b0..7ef275569c1 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -504,6 +504,7 @@ typedef enum NodeTag
T_PartitionSpec,
T_PartitionBoundSpec,
T_PartitionRangeDatum,
+ T_SinglePartitionSpec,
T_PartitionCmd,
T_VacuumRelation,
T_PublicationObjSpec,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 73f635b4553..27556c7c059 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -886,6 +886,18 @@ typedef struct PartitionRangeDatum
int location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about single partition for ALTER TABLE SPLIT PARTITION command
+ * FIXME: need to place this struct into PartitionCmd instead of pair (name, bound)
+ */
+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
*/
@@ -894,6 +906,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;
@@ -2291,6 +2304,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 8a2ab405a28..b58530d0114 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..a0e79a711ba
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..75173e2752a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
Import Notes
Reply to msg id not found: 163714495450.16056.3566953095730878367@malur.postgresql.orgReference msg id not found: 163714495450.16056.3566953095730878367@malur.postgresql.org
On Tue, 31 May 2022 at 11:33, Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi, hackers!
There are not many commands in PostgreSQL for working with partitioned
tables. This is an obstacle to their widespread use.
Adding SPLIT PARTITION/MERGE PARTITIONS operations can make easier to
use partitioned tables in PostgreSQL.
That is quite a nice and useful feature to have.
(This is especially important when migrating projects from ORACLE DBMS.)
SPLIT PARTITION/MERGE PARTITIONS commands are supported for range
partitioning (BY RANGE) and for list partitioning (BY LIST).
For hash partitioning (BY HASH) these operations are not supported.
Just out of curiosity, why is SPLIT / MERGE support not included for
HASH partitions? Because sibling partitions can have a different
modulus, you should be able to e.g. split a partition with (modulus,
remainder) of (3, 1) into two partitions with (mod, rem) of (6, 1) and
(6, 4) respectively, with the reverse being true for merge operations,
right?
Kind regards,
Matthias van de Meent
On Tue, 2022-05-31 at 12:32 +0300, Dmitry Koval wrote:
There are not many commands in PostgreSQL for working with partitioned
tables. This is an obstacle to their widespread use.
Adding SPLIT PARTITION/MERGE PARTITIONS operations can make easier to
use partitioned tables in PostgreSQL.
(This is especially important when migrating projects from ORACLE DBMS.)SPLIT PARTITION/MERGE PARTITIONS commands are supported for range
partitioning (BY RANGE) and for list partitioning (BY LIST).
For hash partitioning (BY HASH) these operations are not supported.
+1 on the general idea.
At least, it will makes these operations simpler, but probably also less
invasive (no need to detach the affected partitions).
I didn't read the patch, but what lock level does that place on the
partitioned table? Anything more than ACCESS SHARE?
Yours,
Laurenz Albe
Just out of curiosity, why is SPLIT / MERGE support not included for
HASH partitions? Because sibling partitions can have a different
modulus, you should be able to e.g. split a partition with (modulus,
remainder) of (3, 1) into two partitions with (mod, rem) of (6, 1) and
(6, 4) respectively, with the reverse being true for merge operations,
right?
You are right, SPLIT/MERGE operations can be added for HASH-partitioning
in the future. But HASH-partitioning is rarer than RANGE- and
LIST-partitioning and I decided to skip it in the first step.
Maybe community will say that SPLIT/MERGE commands are not needed... (At
first step I would like to make sure that it is no true)
P.S. I attached patch with 1-line warning fix (for cfbot).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v2-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v2-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2de0ebacec3..194a720388a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -634,6 +634,11 @@ static List *GetParentedForeignKeyRefs(Relation partition);
static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4383,6 +4388,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4803,6 +4816,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5208,6 +5231,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6195,6 +6234,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17649,6 +17692,35 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartTable: attach new partition to partitioned table
+ *
+ * rel: partitioned relation;
+ * attachRel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartTable(List **wqueue, Relation rel, Relation attachRel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachRel, rel);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachRel, rel, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17841,23 +17913,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. */
+ attachPartTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -19288,3 +19345,663 @@ GetAttributeCompression(Oid atttypid, char *compression)
return cmethod;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartContext;
+
+
+/*
+ * createSplitPartContext: create context for partition and fill it
+ */
+static SplitPartContext *
+createSplitPartContext(Relation partRel)
+{
+ SplitPartContext *pc;
+
+ pc = (SplitPartContext *) palloc0(sizeof(SplitPartContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartContext: delete context for partition
+ */
+static void
+deleteSplitPartContext(SplitPartContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition contect into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ pc = createSplitPartContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = pc;
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartContext((SplitPartContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartTable(NULL, rel, newPartRel, sps->bound);
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop splitted partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ if (!strcmp(name->relname, cmd->name->relname))
+ /* 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.
+ */
+ attachPartTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Unlock and drop merged partitions. */
+ foreach(listptr, partContexts)
+ {
+ ObjectAddress object;
+ MergedPartContext *pc = (MergedPartContext *) lfirst(listptr);
+
+ /* Unlock partition. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ pfree(pc);
+ }
+
+ /* Rename new partition if it is need. */
+ 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/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 51d630fa892..416ad65d528 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -5350,6 +5350,17 @@ _copyPartitionRangeDatum(const PartitionRangeDatum *from)
return newnode;
}
+static SinglePartitionSpec *
+_copySinglePartitionSpec(const SinglePartitionSpec *from)
+{
+ SinglePartitionSpec *newnode = makeNode(SinglePartitionSpec);
+
+ COPY_NODE_FIELD(name);
+ COPY_NODE_FIELD(bound);
+
+ return newnode;
+}
+
static PartitionCmd *
_copyPartitionCmd(const PartitionCmd *from)
{
@@ -5357,6 +5368,7 @@ _copyPartitionCmd(const PartitionCmd *from)
COPY_NODE_FIELD(name);
COPY_NODE_FIELD(bound);
+ COPY_NODE_FIELD(partlist);
COPY_SCALAR_FIELD(concurrent);
return newnode;
@@ -6560,6 +6572,9 @@ copyObjectImpl(const void *from)
case T_PartitionRangeDatum:
retval = _copyPartitionRangeDatum(from);
break;
+ case T_SinglePartitionSpec:
+ retval = _copySinglePartitionSpec(from);
+ break;
case T_PartitionCmd:
retval = _copyPartitionCmd(from);
break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index e747e1667d0..7e217f3e2a9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -3443,11 +3443,21 @@ _equalPartitionRangeDatum(const PartitionRangeDatum *a, const PartitionRangeDatu
return true;
}
+static bool
+_equalSinglePartitionSpec(const SinglePartitionSpec *a, const SinglePartitionSpec *b)
+{
+ COMPARE_NODE_FIELD(name);
+ COMPARE_NODE_FIELD(bound);
+
+ return true;
+}
+
static bool
_equalPartitionCmd(const PartitionCmd *a, const PartitionCmd *b)
{
COMPARE_NODE_FIELD(name);
COMPARE_NODE_FIELD(bound);
+ COMPARE_NODE_FIELD(partlist);
COMPARE_SCALAR_FIELD(concurrent);
return true;
@@ -4363,6 +4373,9 @@ equal(const void *a, const void *b)
case T_PartitionRangeDatum:
retval = _equalPartitionRangeDatum(a, b);
break;
+ case T_SinglePartitionSpec:
+ retval = _equalSinglePartitionSpec(a, b);
+ break;
case T_PartitionCmd:
retval = _equalPartitionCmd(a, b);
break;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 989db0dbece..d860f9021a1 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17862,6 +17914,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17929,6 +17982,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18480,6 +18534,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18559,6 +18614,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1a64a522798..28482597feb 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3273,6 +3275,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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 (!strcmp(name->relname, name2->relname))
+ 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
@@ -3536,7 +3648,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3544,6 +3656,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3935,13 +4065,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3950,9 +4080,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3960,7 +4090,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6b35111ebb6..d7873421d04 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4998,3 +4998,843 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums && found; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ found = false;
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be splitted")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (!strcmp(sps->name->relname, sps2->name->relname))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c3937a60fd3..1622c4f7c32 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12869,3 +12869,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index b3b407579b0..7ef275569c1 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -504,6 +504,7 @@ typedef enum NodeTag
T_PartitionSpec,
T_PartitionBoundSpec,
T_PartitionRangeDatum,
+ T_SinglePartitionSpec,
T_PartitionCmd,
T_VacuumRelation,
T_PublicationObjSpec,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 73f635b4553..27556c7c059 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -886,6 +886,18 @@ typedef struct PartitionRangeDatum
int location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about single partition for ALTER TABLE SPLIT PARTITION command
+ * FIXME: need to place this struct into PartitionCmd instead of pair (name, bound)
+ */
+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
*/
@@ -894,6 +906,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;
@@ -2291,6 +2304,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 8a2ab405a28..b58530d0114 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..a0e79a711ba
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..75173e2752a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
I didn't read the patch, but what lock level does that place on the
partitioned table? Anything more than ACCESS SHARE?
Current patch locks a partitioned table with ACCESS EXCLUSIVE lock.
Unfortunately only this lock guarantees that other session can not work
with partitions that are splitting or merging.
I want add CONCURRENTLY mode in future. With this mode partitioned table
during SPLIT/MERGE operation will be locked with SHARE UPDATE EXCLUSIVE
(as ATTACH/DETACH PARTITION commands in CONCURRENTLY mode).
But in this case queries from other sessions that want to work with
partitions that are splitting/merging at this time should receive an
error (like "Partition data is moving. Repeat the operation later")
because old partitions will be deleted at the end of SPLIT/MERGE operation.
I hope exists a better solution, but I don't know it now...
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Tue, May 31, 2022 at 12:43 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:
Just out of curiosity, why is SPLIT / MERGE support not included for
HASH partitions? Because sibling partitions can have a different
modulus, you should be able to e.g. split a partition with (modulus,
remainder) of (3, 1) into two partitions with (mod, rem) of (6, 1) and
(6, 4) respectively, with the reverse being true for merge operations,
right?You are right, SPLIT/MERGE operations can be added for HASH-partitioning
in the future. But HASH-partitioning is rarer than RANGE- and
LIST-partitioning and I decided to skip it in the first step.
Maybe community will say that SPLIT/MERGE commands are not needed... (At
first step I would like to make sure that it is no true)P.S. I attached patch with 1-line warning fix (for cfbot).
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
For attachPartTable, the parameter wqueue is missing from comment.
The parameters of CloneRowTriggersToPartition are called parent
and partition. I think it is better to name the parameters to
attachPartTable in a similar manner.
For struct SplitPartContext, SplitPartitionContext would be better name.
+ /* Store partition contect into list. */
contect -> context
Cheers
On Tue, May 31, 2022 at 1:43 PM Zhihong Yu <zyu@yugabyte.com> wrote:
On Tue, May 31, 2022 at 12:43 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:Just out of curiosity, why is SPLIT / MERGE support not included for
HASH partitions? Because sibling partitions can have a different
modulus, you should be able to e.g. split a partition with (modulus,
remainder) of (3, 1) into two partitions with (mod, rem) of (6, 1) and
(6, 4) respectively, with the reverse being true for merge operations,
right?You are right, SPLIT/MERGE operations can be added for HASH-partitioning
in the future. But HASH-partitioning is rarer than RANGE- and
LIST-partitioning and I decided to skip it in the first step.
Maybe community will say that SPLIT/MERGE commands are not needed... (At
first step I would like to make sure that it is no true)P.S. I attached patch with 1-line warning fix (for cfbot).
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
For attachPartTable, the parameter wqueue is missing from comment.
The parameters of CloneRowTriggersToPartition are called parent
and partition. I think it is better to name the parameters to
attachPartTable in a similar manner.For struct SplitPartContext, SplitPartitionContext would be better name.
+ /* Store partition contect into list. */
contect -> contextCheers
Hi,
For transformPartitionCmdForMerge(), nested loop is used to detect
duplicate names.
If the number of partitions in partcmd->partlist, we should utilize map to
speed up the check.
For check_parent_values_in_new_partitions():
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts,
nparts, datum, false))
+ found = false;
It seems we can break out of the loop when found is false.
Cheers
Hi,
1)
For attachPartTable, the parameter wqueue is missing from comment.
The parameters of CloneRowTriggersToPartition are called parent and partition.
I think it is better to name the parameters to attachPartTable in a similar manner.For struct SplitPartContext, SplitPartitionContext would be better name.
+ /* Store partition contect into list. */
contect -> context
Thanks, changed.
2)
For transformPartitionCmdForMerge(), nested loop is used to detect duplicate names.
If the number of partitions in partcmd->partlist, we should utilize map to speed up the check.
I'm not sure what we should utilize map in this case because chance that
number of merging partitions exceed dozens is low.
Is there a function example that uses a map for such a small number of
elements?
3)
For check_parent_values_in_new_partitions():
+ if (!find_value_in_new_partitions(&key->partsupfunc[0], + key->partcollation, parts, nparts, datum, false)) + found = false;It seems we can break out of the loop when found is false.
We have implicit "break" in "for" construction:
+ for (i = 0; i < boundinfo->ndatums && found; i++)
I'll change it to explicit "break;" to avoid confusion.
Attached patch with the changes described above.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v3-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v3-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2de0ebacec3..3a2506d9c79 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -634,6 +634,11 @@ static List *GetParentedForeignKeyRefs(Relation partition);
static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4383,6 +4388,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4803,6 +4816,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5208,6 +5231,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6195,6 +6234,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17649,6 +17692,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartTable: 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
+attachPartTable(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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17841,23 +17915,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. */
+ attachPartTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -19288,3 +19347,663 @@ GetAttributeCompression(Oid atttypid, char *compression)
return cmethod;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ pc = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = pc;
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartTable(NULL, rel, newPartRel, sps->bound);
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop splitted partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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.
+ */
+ attachPartTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Unlock and drop merged partitions. */
+ foreach(listptr, partContexts)
+ {
+ ObjectAddress object;
+ MergedPartContext *pc = (MergedPartContext *) lfirst(listptr);
+
+ /* Unlock partition. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ pfree(pc);
+ }
+
+ /* Rename new partition if it is need. */
+ 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/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 51d630fa892..416ad65d528 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -5350,6 +5350,17 @@ _copyPartitionRangeDatum(const PartitionRangeDatum *from)
return newnode;
}
+static SinglePartitionSpec *
+_copySinglePartitionSpec(const SinglePartitionSpec *from)
+{
+ SinglePartitionSpec *newnode = makeNode(SinglePartitionSpec);
+
+ COPY_NODE_FIELD(name);
+ COPY_NODE_FIELD(bound);
+
+ return newnode;
+}
+
static PartitionCmd *
_copyPartitionCmd(const PartitionCmd *from)
{
@@ -5357,6 +5368,7 @@ _copyPartitionCmd(const PartitionCmd *from)
COPY_NODE_FIELD(name);
COPY_NODE_FIELD(bound);
+ COPY_NODE_FIELD(partlist);
COPY_SCALAR_FIELD(concurrent);
return newnode;
@@ -6560,6 +6572,9 @@ copyObjectImpl(const void *from)
case T_PartitionRangeDatum:
retval = _copyPartitionRangeDatum(from);
break;
+ case T_SinglePartitionSpec:
+ retval = _copySinglePartitionSpec(from);
+ break;
case T_PartitionCmd:
retval = _copyPartitionCmd(from);
break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index e747e1667d0..7e217f3e2a9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -3443,11 +3443,21 @@ _equalPartitionRangeDatum(const PartitionRangeDatum *a, const PartitionRangeDatu
return true;
}
+static bool
+_equalSinglePartitionSpec(const SinglePartitionSpec *a, const SinglePartitionSpec *b)
+{
+ COMPARE_NODE_FIELD(name);
+ COMPARE_NODE_FIELD(bound);
+
+ return true;
+}
+
static bool
_equalPartitionCmd(const PartitionCmd *a, const PartitionCmd *b)
{
COMPARE_NODE_FIELD(name);
COMPARE_NODE_FIELD(bound);
+ COMPARE_NODE_FIELD(partlist);
COMPARE_SCALAR_FIELD(concurrent);
return true;
@@ -4363,6 +4373,9 @@ equal(const void *a, const void *b)
case T_PartitionRangeDatum:
retval = _equalPartitionRangeDatum(a, b);
break;
+ case T_SinglePartitionSpec:
+ retval = _equalSinglePartitionSpec(a, b);
+ break;
case T_PartitionCmd:
retval = _equalPartitionCmd(a, b);
break;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 989db0dbece..d860f9021a1 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17862,6 +17914,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17929,6 +17982,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18480,6 +18534,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18559,6 +18614,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1a64a522798..ebf2a8605b0 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3273,6 +3275,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3536,7 +3648,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3544,6 +3656,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3935,13 +4065,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3950,9 +4080,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3960,7 +4090,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6b35111ebb6..aa332e8207d 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4998,3 +4998,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be splitted")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c3937a60fd3..1622c4f7c32 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12869,3 +12869,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index b3b407579b0..7ef275569c1 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -504,6 +504,7 @@ typedef enum NodeTag
T_PartitionSpec,
T_PartitionBoundSpec,
T_PartitionRangeDatum,
+ T_SinglePartitionSpec,
T_PartitionCmd,
T_VacuumRelation,
T_PublicationObjSpec,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 73f635b4553..27556c7c059 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -886,6 +886,18 @@ typedef struct PartitionRangeDatum
int location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about single partition for ALTER TABLE SPLIT PARTITION command
+ * FIXME: need to place this struct into PartitionCmd instead of pair (name, bound)
+ */
+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
*/
@@ -894,6 +906,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;
@@ -2291,6 +2304,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 8a2ab405a28..b58530d0114 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..a0e79a711ba
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..75173e2752a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
On Wed, Jun 1, 2022 at 11:58 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi,
1)
For attachPartTable, the parameter wqueue is missing from comment.
The parameters of CloneRowTriggersToPartition are called parent andpartition.
I think it is better to name the parameters to attachPartTable in a
similar manner.
For struct SplitPartContext, SplitPartitionContext would be better name.
+ /* Store partition contect into list. */
contect -> contextThanks, changed.
2)
For transformPartitionCmdForMerge(), nested loop is used to detect
duplicate names.
If the number of partitions in partcmd->partlist, we should utilize map
to speed up the check.
I'm not sure what we should utilize map in this case because chance that
number of merging partitions exceed dozens is low.
Is there a function example that uses a map for such a small number of
elements?3)
For check_parent_values_in_new_partitions():
+ if (!find_value_in_new_partitions(&key->partsupfunc[0], + key->partcollation, parts,nparts, datum, false))
+ found = false;
It seems we can break out of the loop when found is false.
We have implicit "break" in "for" construction:
+ for (i = 0; i < boundinfo->ndatums && found; i++)
I'll change it to explicit "break;" to avoid confusion.
Attached patch with the changes described above.
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
Thanks for your response.
w.r.t. #2, I think using nested loop is fine for now.
If, when this feature is merged, some user comes up with long merge list,
we can revisit this topic.
Cheers
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v4-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v4-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f2947ea9b49..0215f224162 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -635,6 +635,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4387,6 +4392,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4807,6 +4820,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5212,6 +5235,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6200,6 +6239,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17623,6 +17666,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartTable: 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
+attachPartTable(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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17815,23 +17889,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. */
+ attachPartTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -19297,3 +19356,663 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ pc = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = pc;
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartTable(NULL, rel, newPartRel, sps->bound);
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop splitted partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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.
+ */
+ attachPartTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Unlock and drop merged partitions. */
+ foreach(listptr, partContexts)
+ {
+ ObjectAddress object;
+ MergedPartContext *pc = (MergedPartContext *) lfirst(listptr);
+
+ /* Unlock partition. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ pfree(pc);
+ }
+
+ /* Rename new partition if it is need. */
+ 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 c018140afe4..ad38e1d456f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17872,6 +17924,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17939,6 +17992,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18490,6 +18544,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18569,6 +18624,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index b57253463b9..8c500014ad3 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3271,6 +3273,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3534,7 +3647,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3542,6 +3655,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3933,13 +4064,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3948,9 +4079,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3958,7 +4089,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b6..c85e602535a 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be splitted")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 26cf4fa9a0e..d9089bc7af6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12865,3 +12865,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b0c9c5f2ef6..c351dc48f36 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2302,6 +2314,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 ae35f032513..58d8ec14b9d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/modules/test_oat_hooks/test_oat_hooks.c b/src/test/modules/test_oat_hooks/test_oat_hooks.c
index 900d597f5dd..13b83f39df5 100644
--- a/src/test/modules/test_oat_hooks/test_oat_hooks.c
+++ b/src/test/modules/test_oat_hooks/test_oat_hooks.c
@@ -1644,6 +1644,9 @@ nodetag_to_string(NodeTag tag)
case T_PartitionRangeDatum:
return "PartitionRangeDatum";
break;
+ case T_SinglePartitionSpec:
+ return "SinglePartitionSpec";
+ break;
case T_PartitionCmd:
return "PartitionCmd";
break;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..a0e79a711ba
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..75173e2752a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of splitted partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 34a76ceb60f..4f4f8c9ffff 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2525,6 +2525,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
On Wed, Jul 13, 2022 at 11:28 AM Dmitry Koval <d.koval@postgrespro.ru>
wrote:
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
+attachPartTable(List **wqueue, Relation rel, Relation partition,
PartitionBoundSpec *bound)
I checked naming of existing methods, such as AttachPartitionEnsureIndexes.
I think it would be better if the above method is
named attachPartitionTable.
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ pc = createSplitPartitionContext(table_open(defaultPartOid,
AccessExclusiveLock));
Since the value of pc would be passed to defaultPartCtx, there is no need
to assign to pc above. You can assign directly to defaultPartCtx.
+ /* Drop splitted partition. */
splitted -> split
+ /* Rename new partition if it is need. */
need -> needed.
Cheers
Thanks you!
I've fixed all things mentioned.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v5-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v5-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f2947ea9b49..c6a8fffa60b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -635,6 +635,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4387,6 +4392,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4807,6 +4820,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5212,6 +5235,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6200,6 +6239,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17623,6 +17666,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17815,23 +17889,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.
@@ -19297,3 +19356,661 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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);
+
+ /* Unlock partition. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ 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 c018140afe4..ad38e1d456f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17872,6 +17924,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17939,6 +17992,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18490,6 +18544,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18569,6 +18624,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index b57253463b9..8c500014ad3 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3271,6 +3273,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3534,7 +3647,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3542,6 +3655,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3933,13 +4064,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3948,9 +4079,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3958,7 +4089,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b6..4c55115074b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 26cf4fa9a0e..d9089bc7af6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12865,3 +12865,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b0c9c5f2ef6..c351dc48f36 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2302,6 +2314,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 ae35f032513..58d8ec14b9d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/modules/test_oat_hooks/test_oat_hooks.c b/src/test/modules/test_oat_hooks/test_oat_hooks.c
index 900d597f5dd..13b83f39df5 100644
--- a/src/test/modules/test_oat_hooks/test_oat_hooks.c
+++ b/src/test/modules/test_oat_hooks/test_oat_hooks.c
@@ -1644,6 +1644,9 @@ nodetag_to_string(NodeTag tag)
case T_PartitionRangeDatum:
return "PartitionRangeDatum";
break;
+ case T_SinglePartitionSpec:
+ return "SinglePartitionSpec";
+ break;
case T_PartitionCmd:
return "PartitionCmd";
break;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..7caf766f0b4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..6d017f2e919
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 34a76ceb60f..4f4f8c9ffff 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2525,6 +2525,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
On Wed, Jul 13, 2022 at 1:05 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thanks you!
I've fixed all things mentioned.--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
Toward the end of ATExecSplitPartition():
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);
Why is NoLock passed (instead of AccessExclusiveLock) ?
Cheers
+ /* Unlock new partition. */
+ table_close(newPartRel, NoLock);Why is NoLock passed (instead of AccessExclusiveLock) ?
Thanks!
You're right, I replaced the comment with "Keep the lock until commit.".
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v6-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v6-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f2947ea9b49..0703e36ff76 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -635,6 +635,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4387,6 +4392,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4807,6 +4820,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5212,6 +5235,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6200,6 +6239,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17623,6 +17666,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17815,23 +17889,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.
@@ -19297,3 +19356,661 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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);
+
+ /* Keep the lock until commit. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ 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 c018140afe4..ad38e1d456f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -826,7 +829,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -840,7 +843,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2342,6 +2345,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2366,6 +2387,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2379,6 +2401,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2395,6 +2446,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17872,6 +17924,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17939,6 +17992,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18490,6 +18544,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18569,6 +18624,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index b57253463b9..8c500014ad3 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3271,6 +3273,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3534,7 +3647,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3542,6 +3655,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3933,13 +4064,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3948,9 +4079,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3958,7 +4089,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b6..4c55115074b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 26cf4fa9a0e..d9089bc7af6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12865,3 +12865,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b0c9c5f2ef6..c351dc48f36 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2302,6 +2314,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 ae35f032513..58d8ec14b9d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..34df1345b2b
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..e10c7c607a6
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/modules/test_oat_hooks/test_oat_hooks.c b/src/test/modules/test_oat_hooks/test_oat_hooks.c
index 900d597f5dd..13b83f39df5 100644
--- a/src/test/modules/test_oat_hooks/test_oat_hooks.c
+++ b/src/test/modules/test_oat_hooks/test_oat_hooks.c
@@ -1644,6 +1644,9 @@ nodetag_to_string(NodeTag tag)
case T_PartitionRangeDatum:
return "PartitionRangeDatum";
break;
+ case T_SinglePartitionSpec:
+ return "SinglePartitionSpec";
+ break;
case T_PartitionCmd:
return "PartitionCmd";
break;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..7caf766f0b4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..6d017f2e919
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 34a76ceb60f..4f4f8c9ffff 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2525,6 +2525,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
This is not a review, but I think the isolation tests should be
expanded. At least, include the case of serializable transactions being
involved.
--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
"Pensar que el espectro que vemos es ilusorio no lo despoja de espanto,
sólo le suma el nuevo terror de la locura" (Perelandra, C.S. Lewis)
This is not a review, but I think the isolation tests should be
expanded. At least, include the case of serializable transactions being
involved.
Thanks!
I will expand the tests for the next commitfest.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v7-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v7-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 70b94bbb39..684df4b80e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4401,6 +4406,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4835,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5243,6 +5266,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6231,6 +6270,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17641,6 +17684,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17833,23 +17907,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.
@@ -19314,3 +19373,661 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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);
+
+ /* Keep the lock until commit. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ 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 f9037761f9..9162818678 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -649,6 +650,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -831,7 +834,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -845,7 +848,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2366,6 +2369,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2376,6 +2396,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2390,6 +2411,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2403,6 +2425,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2419,6 +2470,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17826,6 +17878,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17893,6 +17946,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18444,6 +18498,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18523,6 +18578,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6d283006e3..5c68756aeb 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3281,6 +3283,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3544,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3552,6 +3665,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3943,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3958,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3968,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b..4c55115074 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d575aa0066..025971f94e 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12901,3 +12901,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b376031856..3e2fcf302b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2302,6 +2314,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 ae35f03251..58d8ec14b9 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b840..3630c0eaef 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 0000000000..34df1345b2
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,36 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+-----
+1|text1
+(1 row)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text1');
+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 = 'text1modif' where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+i|t
+-+----------
+1|text1modif
+(1 row)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 529a4cbd4d..22e81b01a4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 0000000000..e10c7c607a
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,43 @@
+# Verify that SPLIT and MERGE operations 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;
+}
+
+teardown
+{
+ DROP TABLE tpart;
+}
+
+session s1
+step s1b { BEGIN; }
+step s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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 s2i { INSERT INTO tpart VALUES (1, 'text1'); }
+step s2u { UPDATE tpart SET t = 'text1modif' where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+permutation s1b s1splt s2b s2i s1c s2c s2s
+
+# 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
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 0000000000..c783c4ad09
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d..c6f974d7b5 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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..5a724ce65d
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 35c9f1efce..9cd0f11505 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2525,6 +2525,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
I will expand the tests for the next commitfest.
Hi!
Combinations of isolation modes (READ COMMITTED/REPEATABLE
READ/SERIALIZABLE) were added to test
src/test/isolation/specs/partition-split-merge.spec
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v8-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v8-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dacc989d855..a4f989b9773 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4401,6 +4406,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4835,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5243,6 +5266,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6231,6 +6270,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17641,6 +17684,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17833,23 +17907,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.
@@ -19314,3 +19373,661 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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);
+
+ /* Keep the lock until commit. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ 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 b5ab9d9c9a3..7ee85819a8e 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -652,6 +653,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -834,7 +837,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -848,7 +851,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
- SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2369,6 +2372,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2379,6 +2399,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2393,6 +2414,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2406,6 +2428,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2422,6 +2473,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17859,6 +17911,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -17926,6 +17979,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18477,6 +18531,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18556,6 +18611,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6d283006e3d..5c68756aebc 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3281,6 +3283,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3544,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3552,6 +3665,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3943,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3958,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3968,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b6..4c55115074b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9959f6910e9..9f3abfdfdd0 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12899,3 +12899,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 469a5c46f62..efa2de05cfa 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2302,6 +2314,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 ae35f032513..58d8ec14b9d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -415,6 +416,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b8400..3630c0eaef6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a35..ed13a43f53d 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 00000000000..b2f224cc232
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,388 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 529a4cbd4da..22e81b01a4b 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 00000000000..1da8f642d10
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,73 @@
+# Verify that SPLIT and MERGE operations 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# 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/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 00000000000..c783c4ad098
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..7caf766f0b4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 103e11483d2..c6f974d7b5c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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 00000000000..5a724ce65db
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..6d017f2e919
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 8ad112c44d0..bd1e6f0c01a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2528,6 +2528,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v9-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v9-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dacc989d85..a4f989b977 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4401,6 +4406,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4835,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5243,6 +5266,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6231,6 +6270,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17641,6 +17684,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17833,23 +17907,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.
@@ -19314,3 +19373,661 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ /* Keep the lock until commit. */
+ table_close(defaultPartCtx->partRel, NoLock);
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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);
+
+ /* Keep the lock until commit. */
+ table_close(pc->partRel, NoLock);
+
+ object.classId = RelationRelationId;
+ object.objectId = RelationGetRelid(pc->partRel);
+ object.objectSubId = 0;
+ 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 0492ff9a66..c829872295 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -731,7 +734,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
@@ -745,7 +748,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2254,6 +2257,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2264,6 +2284,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2278,6 +2299,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2291,6 +2313,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2307,6 +2358,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16829,6 +16881,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -16892,6 +16945,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17410,6 +17464,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLACING
@@ -17485,6 +17540,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6d283006e3..5c68756aeb 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3281,6 +3283,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3544,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3552,6 +3665,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3943,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3958,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3968,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b..4c55115074 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2b7b1b0c0f..7ec7413c1b 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12228,3 +12228,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6958306a7d..2e44f2db77 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2015,6 +2027,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 9a7cc0c6bd..a3569cad0b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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)
@@ -391,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b840..3630c0eaef 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 0000000000..b2f224cc23
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,388 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 529a4cbd4d..22e81b01a4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 0000000000..1da8f642d1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,73 @@
+# Verify that SPLIT and MERGE operations 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# 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/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 0000000000..c783c4ad09
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 9f644a0c1b..b975fe295c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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..5a724ce65d
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 5b3b305963..1626acd430 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2514,6 +2514,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
On Wed, Sep 07, 2022 at 08:03:09PM +0300, Dmitry Koval wrote:
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.
This crashes on freebsd with -DRELCACHE_FORCE_RELEASE
https://cirrus-ci.com/task/6565371623768064
https://cirrus-ci.com/task/6145355992530944
Note that that's a modified cirrus script from my CI improvements branch
which also does some extra/different things.
--
Justin
Thanks a lot Justin!
After compilation PostgreSQL+patch with macros
RELCACHE_FORCE_RELEASE,
COPY_PARSE_PLAN_TREES,
WRITE_READ_PARSE_PLAN_TREES,
RAW_EXPRESSION_COVERAGE_TEST,
RANDOMIZE_ALLOCATED_MEMORY,
I saw a problem on Windows 10, MSVC2019.
(I hope this problem was the same as on Cirrus CI).
Attached patch with fix.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v10-0001-partitions-split-merge.patchtext/plain; charset=UTF-8; name=v10-0001-partitions-split-merge.patchDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dacc989d85..3c8c7aec9e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,11 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4401,6 +4406,14 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4835,16 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* 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);
@@ -5243,6 +5266,22 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ 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);
@@ -6231,6 +6270,10 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
+ case AT_MergePartitions:
+ return "MERGE PARTITIONS";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -17641,6 +17684,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17833,23 +17907,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.
@@ -19314,3 +19373,665 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
+/*
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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 0492ff9a66..c829872295 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -273,6 +273,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -731,7 +734,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
@@ -745,7 +748,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2254,6 +2257,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2264,6 +2284,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2278,6 +2299,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2291,6 +2313,35 @@ 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 <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2307,6 +2358,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16829,6 +16881,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -16892,6 +16945,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17410,6 +17464,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLACING
@@ -17485,6 +17540,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6d283006e3..5c68756aeb 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"
@@ -135,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3281,6 +3283,117 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
+/*
+ * 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
@@ -3544,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3552,6 +3665,24 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
+ 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")));
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -3943,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -3958,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -3968,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 091d6e886b..4c55115074 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4999,3 +4999,846 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_name->relname),
+ parser_errposition(pstate, datum->location)));
+ }
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
+/*
+ * 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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2b7b1b0c0f..7ec7413c1b 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12228,3 +12228,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6958306a7d..2e44f2db77 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2015,6 +2027,8 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
+ 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 9a7cc0c6bd..a3569cad0b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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)
@@ -391,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index b1e3f1b840..3630c0eaef 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,4 +143,14 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
+extern void calculate_partition_bound_for_merge(Relation parent,
+ List *partNames,
+ List *partOids,
+ PartitionBoundSpec *spec,
+ ParseState *pstate);
+
#endif /* PARTBOUNDS_H */
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split-merge.out b/src/test/isolation/expected/partition-split-merge.out
new file mode 100644
index 0000000000..b2f224cc23
--- /dev/null
+++ b/src/test/isolation/expected/partition-split-merge.out
@@ -0,0 +1,388 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 529a4cbd4d..22e81b01a4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -101,6 +101,7 @@ test: partition-key-update-1
test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
+test: partition-split-merge
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split-merge.spec b/src/test/isolation/specs/partition-split-merge.spec
new file mode 100644
index 0000000000..1da8f642d1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split-merge.spec
@@ -0,0 +1,73 @@
+# Verify that SPLIT and MERGE operations 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20)); }
+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; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# 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/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
new file mode 100644
index 0000000000..c783c4ad09
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,715 @@
+--
+-- 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;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- 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/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 9f644a0c1b..b975fe295c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_split 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..5a724ce65d
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,411 @@
+--
+-- 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;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- 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/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 5b3b305963..1626acd430 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2514,6 +2514,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
On Thu, Sep 08, 2022 at 02:35:24PM +0300, Dmitry Koval wrote:
Thanks a lot Justin!
After compilation PostgreSQL+patch with macros
RELCACHE_FORCE_RELEASE,
RANDOMIZE_ALLOCATED_MEMORY,
I saw a problem on Windows 10, MSVC2019.
Yes, it passes tests on my CI improvements branch.
https://github.com/justinpryzby/postgres/runs/8248668269
Thanks to Alexander Pyhalov for reminding me about
RELCACHE_FORCE_RELEASE last year ;)
On Tue, May 31, 2022 at 12:32:43PM +0300, Dmitry Koval wrote:
This can be useful for this example cases:
need to merge all one-day partitions
into a month partition.
+1, we would use this (at least the MERGE half).
I wonder if it's possible to reduce the size of this patch (I'm starting
to try to absorb it). Is there a way to refactor/reuse existing code to
reduce its footprint ?
partbounds.c is adding 500+ LOC about checking if proposed partitions
meet the requirements (don't overlap, etc). But a lot of those checks
must already happen, no? Can you re-use/refactor the existing checks ?
An UPDATE on a partitioned table will move tuples from one partition to
another. Is there a way to re-use that ? Also, postgres already
supports concurrent DDL (CREATE+ATTACH and DETACH CONCURRENTLY). Is it
possible to leverage that ? (Mostly to reduce the patch size, but also
because maybe some cases could be concurrent?).
If the patch were split into separate parts for MERGE and SPLIT, would
the first patch be significantly smaller than the existing patch
(hopefully half as big) ? That would help to review it, even if both
halves were ultimately squished together. (An easy way to do this is to
open up all the files in separate editor instances, trim out the parts
that aren't needed for the first patch, save the files but don't quit
the editors, test compilation and regression tests, then git commit
--amend -a. Then in each editor, "undo" all the trimmed changes, save,
and git commit -a).
Would it save much code if "default" partitions weren't handled in the
first patch ?
--
Justin
On 2022-Sep-08, Justin Pryzby wrote:
If the patch were split into separate parts for MERGE and SPLIT, would
the first patch be significantly smaller than the existing patch
(hopefully half as big) ? That would help to review it, even if both
halves were ultimately squished together. (An easy way to do this is to
open up all the files in separate editor instances, trim out the parts
that aren't needed for the first patch, save the files but don't quit
the editors, test compilation and regression tests, then git commit
--amend -a. Then in each editor, "undo" all the trimmed changes, save,
and git commit -a).
An easier (IMO) way to do that is to use "git gui" or even "git add -p",
which allow you to selectively add changed lines/hunks to the index.
You add a few, commit, then add the rest, commit again. With "git add
-p" you can even edit individual hunks in an editor in case you have a
mix of both wanted and unwanted in a single hunk (after "s"plitting, of
course), which turns out to be easier than it sounds.
--
Álvaro Herrera PostgreSQL Developer — https://www.EnterpriseDB.com/
"El sudor es la mejor cura para un pensamiento enfermo" (Bardia)
Thanks for your advice, Justin and Alvaro!
I'll try to reduce the size of this patch and split it into separate
parts (for MERGE and SPLIT).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi!
Two separate parts for MERGE and SPLIT partitions (without refactoring;
it will be later)
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v11-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v11-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 20317e7f2dbd65cbbaa075092db50ac97f6dd03c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v11 1/2] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 347 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 184 +++++
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 ++
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 +
14 files changed, 2070 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 e3233a8f38..9ae3855673 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,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
@@ -4401,6 +4403,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4828,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);
@@ -5243,6 +5254,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);
@@ -6231,6 +6250,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:
@@ -17653,6 +17674,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17845,23 +17897,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.
@@ -19326,3 +19363,279 @@ 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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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 82f03fc9c9..c48a732f5d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -728,7 +728,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
@@ -2261,6 +2261,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2275,6 +2276,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2288,6 +2290,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2304,6 +2321,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16826,6 +16844,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17407,6 +17426,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 6d283006e3..8dfb94acb4 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"
@@ -3281,6 +3283,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
@@ -3552,6 +3628,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 57c9b51814..2068565ed2 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5000,3 +5000,187 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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 6958306a7d..c609f92deb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -895,6 +895,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
*/
@@ -903,6 +914,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;
@@ -2015,6 +2027,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 9a7cc0c6bd..d0d76260bc 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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 b1e3f1b840..850b1add50 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 5413a59a80..d91032c42a 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/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 9f644a0c1b..5153c923bf 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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 5b3b305963..1626acd430 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2514,6 +2514,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.31.0.windows.1
v11-0002-PGPRO-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v11-0002-PGPRO-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 4bd294311dafa4d8a47e74a40e1982f2633b42c9 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v11 2/2] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 408 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 659 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
src/test/regress/expected/partition_split.out | 1425 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 839 ++++++++++
15 files changed, 3692 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9ae3855673..b2778aefe5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4403,6 +4406,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4828,6 +4835,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5254,6 +5266,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6250,6 +6270,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19364,6 +19386,256 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ SplitPartitionContext *pc;
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19418,6 +19690,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c48a732f5d..083071e4c4 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -642,6 +643,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -742,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
@@ -2251,6 +2254,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2295,6 +2315,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16908,6 +16942,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17502,6 +17537,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 8dfb94acb4..5c68756aeb 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3283,6 +3283,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3620,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3628,6 +3665,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3636,7 +3674,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4032,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4047,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4057,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 2068565ed2..5283870e32 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5046,6 +5046,665 @@ check_partitions_not_overlap_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* get_partition_bound_spec
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2b7b1b0c0f..7ec7413c1b 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12228,3 +12228,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index c609f92deb..2e44f2db77 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2027,6 +2027,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index d0d76260bc..a3569cad0b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -392,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 850b1add50..3630c0eaef 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index d91032c42a..cbaf030858 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5153c923bf..b975fe295c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
On Tue, May 31, 2022 at 5:33 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
There are not many commands in PostgreSQL for working with partitioned
tables. This is an obstacle to their widespread use.
Adding SPLIT PARTITION/MERGE PARTITIONS operations can make easier to
use partitioned tables in PostgreSQL.
(This is especially important when migrating projects from ORACLE DBMS.)SPLIT PARTITION/MERGE PARTITIONS commands are supported for range
partitioning (BY RANGE) and for list partitioning (BY LIST).
For hash partitioning (BY HASH) these operations are not supported.
This may be a good idea, but I would like to point out one
disadvantage of this approach.
If you know that a certain partition is not changing, and you would
like to split it, you can create two or more new standalone tables and
populate them from the original partition using INSERT .. SELECT. Then
you can BEGIN a transaction, DETACH the existing partitions, and
ATTACH the replacement ones. By doing this, you take an ACCESS
EXCLUSIVE lock on the partitioned table only for a brief period. The
same kind of idea can be used to merge partitions.
It seems hard to do something comparable with built-in DDL for SPLIT
PARTITION and MERGE PARTITION. You could start by taking e.g. SHARE
lock on the existing partition(s) and then wait until the end to take
ACCESS EXCLUSIVE lock on the partitions, but we typically avoid such
coding patterns, because the lock upgrade might deadlock and then a
lot of work would be wasted. So most likely with the approach you
propose here you will end up acquiring ACCESS EXCLUSIVE lock at the
beginning of the operation and then shuffle a lot of data around while
still holding it, which is pretty painful.
Because of this problem, I find it hard to believe that these commands
would get much use, except perhaps on small tables or in
non-production environments, unless people just didn't know about the
alternatives. That's not to say that something like this has no value.
As a convenience feature, it's fine. It's just hard for me to see it
as any more than that.
--
Robert Haas
EDB: http://www.enterprisedb.com
Thanks for comments and advice!
I thought about this problem and discussed about it with colleagues.
Unfortunately, I don't know of a good general solution.
19.09.2022 22:56, Robert Haas пишет:
If you know that a certain partition is not changing, and you would
like to split it, you can create two or more new standalone tables and
populate them from the original partition using INSERT .. SELECT. Then
you can BEGIN a transaction, DETACH the existing partitions, and
ATTACH the replacement ones. By doing this, you take an ACCESS
EXCLUSIVE lock on the partitioned table only for a brief period. The
same kind of idea can be used to merge partitions.
But for specific situation like this (certain partition is not changing)
we can add CONCURRENTLY modifier.
Our DDL query can be like
ALTER TABLE...SPLIT PARTITION [CONCURRENTLY];
With CONCURRENTLY modifier we can lock partitioned table in
ShareUpdateExclusiveLock mode and split partition - in
AccessExclusiveLock mode. So we don't lock partitioned table in
AccessExclusiveLock mode and can modify other partitions during SPLIT
operation (except split partition).
If smb try to modify split partition, he will receive error "relation
does not exist" at end of operation (because split partition will be drop).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Mon, Sep 19, 2022 at 4:42 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thanks for comments and advice!
I thought about this problem and discussed about it with colleagues.
Unfortunately, I don't know of a good general solution.
Yeah, me neither.
But for specific situation like this (certain partition is not changing)
we can add CONCURRENTLY modifier.
Our DDL query can be likeALTER TABLE...SPLIT PARTITION [CONCURRENTLY];
With CONCURRENTLY modifier we can lock partitioned table in
ShareUpdateExclusiveLock mode and split partition - in
AccessExclusiveLock mode. So we don't lock partitioned table in
AccessExclusiveLock mode and can modify other partitions during SPLIT
operation (except split partition).
If smb try to modify split partition, he will receive error "relation
does not exist" at end of operation (because split partition will be drop).
I think that a built-in DDL command can't really assume that the user
won't modify anything. You'd have to take a ShareLock.
But you might be able to have a CONCURRENTLY variant of the command
that does the same kind of multi-transaction thing as, e.g., CREATE
INDEX CONCURRENTLY. You would probably have to be quite careful about
race conditions (e.g. you commit the first transaction and before you
start the second one, someone drops or detaches the partition you were
planning to merge or split). Might take some thought, but feels
possibly doable. I've never been excited enough about this kind of
thing to want to put a lot of energy into engineering it, because
doing it "manually" feels so much nicer to me, and doubly so given
that we now have ATTACH CONCURRENTLY and DETACH CONCURRENTLY, but it
does seem like a thing some people would probably use and value.
--
Robert Haas
EDB: http://www.enterprisedb.com
Hi!
Fixed couple warnings (for cfbot).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v12-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v12-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 357187cefcef4e9340f5c6798ddeef9e4e62f15d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v12 1/2] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 347 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 184 +++++
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 ++
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 +
14 files changed, 2070 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 20135ef1b0..c6e1ba6dca 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,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
@@ -4401,6 +4403,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4828,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);
@@ -5243,6 +5254,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);
@@ -6231,6 +6250,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:
@@ -17639,6 +17660,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17831,23 +17883,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.
@@ -19312,3 +19349,279 @@ 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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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))));
+
+ 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 94d5142a4a..81443151e8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -727,7 +727,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
@@ -2261,6 +2261,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2275,6 +2276,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2288,6 +2290,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2304,6 +2321,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16833,6 +16851,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17415,6 +17434,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 bd068bba05..02521e1b6d 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"
@@ -3281,6 +3283,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
@@ -3552,6 +3628,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 0823fa7b1d..1fa0a73978 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5000,3 +5000,187 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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 633e7671b3..6c294df786 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -896,6 +896,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
*/
@@ -904,6 +915,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;
@@ -2016,6 +2028,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 ccc927851c..09b028acba 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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 1f5b706d83..435668fb7c 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 5413a59a80..d91032c42a 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/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 9f644a0c1b..5153c923bf 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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 d9b839c979..fffb780b7c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2515,6 +2515,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.31.0.windows.1
v12-0002-PGPRO-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v12-0002-PGPRO-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From e5b71c79bb1c308e32bb5024474413cbc44a24e7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v12 2/2] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 659 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
src/test/regress/expected/partition_split.out | 1425 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 839 ++++++++++
15 files changed, 3691 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index c6e1ba6dca..c230c0f894 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4403,6 +4406,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4828,6 +4835,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5254,6 +5266,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6250,6 +6270,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19350,6 +19372,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19404,6 +19675,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 81443151e8..bdadeb6066 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -269,6 +269,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -741,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2251,6 +2254,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2295,6 +2315,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16915,6 +16949,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17510,6 +17545,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 02521e1b6d..ada9d6c754 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3283,6 +3283,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3620,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3628,6 +3665,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3636,7 +3674,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4032,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4047,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4057,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 1fa0a73978..4690a1d8f1 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5046,6 +5046,665 @@ check_partitions_not_overlap_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, Abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ Abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* get_partition_bound_spec
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 855d48372a..0f39312efd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12232,3 +12232,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6c294df786..0ab6daea0b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2028,6 +2028,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 09b028acba..192341c0c3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -392,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 435668fb7c..d496d6ac4b 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index d91032c42a..cbaf030858 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5153c923bf..b975fe295c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
On Tue, Oct 11, 2022 at 9:22 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Fixed couple warnings (for cfbot).
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
For v12-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patch:
+ if (equal(name, cmd->name))
+ /* One new partition can have the same name as merged
partition. */
+ isSameName = true;
I think there should be a check before assigning true to isSameName - if
isSameName is true, that means there are two partitions with this same name.
Cheers
On Tue, Oct 11, 2022 at 9:58 AM Zhihong Yu <zyu@yugabyte.com> wrote:
On Tue, Oct 11, 2022 at 9:22 AM Dmitry Koval <d.koval@postgrespro.ru>
wrote:Hi!
Fixed couple warnings (for cfbot).
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
Hi,
For v12-0001-PGPRO-ALTER-TABLE-MERGE-PARTITIONS-command.patch:+ if (equal(name, cmd->name)) + /* One new partition can have the same name as merged partition. */ + isSameName = true;I think there should be a check before assigning true to isSameName - if
isSameName is true, that means there are two partitions with this same name.Cheers
Pardon - I see that transformPartitionCmdForMerge() compares the partition
names.
Maybe you can add a comment in ATExecMergePartitions referring to
transformPartitionCmdForMerge() so that people can more easily understand
the logic.
Hi!
Maybe you can add a comment in ATExecMergePartitions referring to
transformPartitionCmdForMerge() so that people can more easily
understand the logic.
Thanks, comment added.
Patch stop applying due to changes in upstream.
Here is a fixed version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v13-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v13-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From e191d4c4959cb999c679309342a3425658b074f8 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v13 1/2] 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 | 184 +++++
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 ++
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 +
14 files changed, 2074 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 20135ef1b0..2deae2b0fb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,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
@@ -4401,6 +4403,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4828,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);
@@ -5243,6 +5254,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);
@@ -6231,6 +6250,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:
@@ -17639,6 +17660,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17831,23 +17883,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.
@@ -19312,3 +19349,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 94d5142a4a..81443151e8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -727,7 +727,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
@@ -2261,6 +2261,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2275,6 +2276,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2288,6 +2290,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2304,6 +2321,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16833,6 +16851,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17415,6 +17434,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 bd068bba05..02521e1b6d 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"
@@ -3281,6 +3283,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
@@ -3552,6 +3628,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 0823fa7b1d..1fa0a73978 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5000,3 +5000,187 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(rowHash % modulus == remainder);
}
+
+/*
+ * check_partitions_not_overlap_range
+ *
+ * Checks that bounds of partitions (name, bound) and (prev_name, prev_bound)
+ * do not overlap. Lower bound of partition "prev_name" should be less or equal
+ * than lower bound of partition "name".
+ * In case defaultPart=true can be free space between bound and prev_bound.
+ */
+static void
+check_partitions_not_overlap_range(Relation parent,
+ RangeVar *name,
+ PartitionBoundSpec *bound,
+ RangeVar *prev_name,
+ PartitionBoundSpec *prev_bound,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower;
+ PartitionRangeBound *prevupper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, bound->lowerdatums, true);
+ prevupper = make_one_partition_rbound(key, -1, prev_bound->upperdatums, false);
+
+ /* lower1=false for correct comparison lower and upper bounds */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ false, prevupper);
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ {
+ PartitionRangeDatum *datum = linitial(bound->lowerdatums);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ name->relname, prev_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 bound of merged partition "spec" by using bounds of partitions
+ * with Oids "partOids" and names "partNames".
+ */
+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_partitions_not_overlap_range(parent,
+ (RangeVar *) list_nth(partNames, index),
+ (PartitionBoundSpec *) list_nth(bounds, index),
+ (RangeVar *) list_nth(partNames, prev_index),
+ (PartitionBoundSpec *) list_nth(bounds, prev_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 633e7671b3..6c294df786 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -896,6 +896,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
*/
@@ -904,6 +915,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;
@@ -2016,6 +2028,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 ccc927851c..09b028acba 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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 1f5b706d83..435668fb7c 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 5413a59a80..d91032c42a 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/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 9f644a0c1b..5153c923bf 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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 d9b839c979..fffb780b7c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2515,6 +2515,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.31.0.windows.1
v13-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v13-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 87299755634340446123b87ff1205109643267b7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v13 2/2] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 659 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
src/test/regress/expected/partition_split.out | 1425 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 839 ++++++++++
15 files changed, 3691 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2deae2b0fb..ebcb651a22 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -637,6 +637,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4403,6 +4406,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4828,6 +4835,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5254,6 +5266,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6250,6 +6270,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19350,6 +19372,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19404,6 +19675,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 81443151e8..bdadeb6066 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -269,6 +269,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -741,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2251,6 +2254,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2295,6 +2315,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16915,6 +16949,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17510,6 +17545,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 02521e1b6d..ada9d6c754 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3283,6 +3283,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3620,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3628,6 +3665,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3636,7 +3674,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4032,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4047,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4057,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 1fa0a73978..24418fa8ba 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5046,6 +5046,665 @@ check_partitions_not_overlap_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * Checks that values of new partitions do not overlap.
+ * parts: array of SinglePartitionSpec structs
+ * nparts: size of array "parts".
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid). If first=true then lower bounds of partitions should
+ * be equals. If last=true then upper bounds of partitions should be equals.
+ * If defined spsPrev then function compares lower bound of spec with upper
+ * bound of spsPrev.
+ * defaultPart=true in case partitioned table has DEFAULT partition.
+ */
+static void
+check_partition_bounds_for_split_range(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums,
+ cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ if (partdesc->nparts > 0)
+ {
+ int offset;
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_RANGE &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_has_default(boundinfo)));
+
+ /*
+ * Test whether the new lower bound (which is treated inclusively as
+ * part of the new partition) lies inside an existing partition, or in
+ * a gap.
+ *
+ * If it's inside an existing partition, the bound at offset + 1 will
+ * be the upper bound of that partition, and its index will be >= 0.
+ *
+ * If it's in a gap, the bound at offset + 1 will be the lower bound
+ * of the next partition, and its index will be -1. This is also true
+ * if there is no next partition, since the index array is initialised
+ * with an extra -1 at the end.
+ */
+ offset = partition_range_bsearch(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ boundinfo, lower,
+ &cmpval);
+
+ if (boundinfo->indexes[offset + 1] < 0)
+ {
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("bounds of partition \"%s\" are outside bounds of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ /*
+ * The new partition overlaps with the existing partition between
+ * offset and offset + 1.
+ */
+ PartitionRangeDatum *datum;
+
+ /*
+ * Point to problematic key in the lower datums list; if we have
+ * equality, point to the first one.
+ */
+ datum = cmpval == 0 ? linitial(spec->lowerdatums) :
+ list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ overlap_location = datum->location;
+ with = boundinfo->indexes[offset + 1];
+ if (partdesc->oids[with] != splitPartOid)
+ overlap = true;
+ else if (first || last)
+ {
+ /*
+ * Lower bound of first partition should be equals to lower
+ * bound of split partition. Upper bound of last partition
+ * should be equals to upper bound of split partition.
+ *
+ * Need to do exact check of this condition if not exists
+ * DEFAULT partition. Otherwise can be spaces between
+ * partitions.
+ */
+ Datum *datums;
+ PartitionRangeDatumKind *kind;
+ int curoffset = offset + (last ? 1 : 0);
+
+ datums = boundinfo->datums[curoffset];
+ kind = boundinfo->kind[curoffset];
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ datums, kind,
+ first,
+ first ? lower : upper);
+ if ((!defaultPart && cmpval) ||
+ /* Is partition bound outside of split partition bound? */
+ (defaultPart && first && cmpval > 0) ||
+ (defaultPart && last && cmpval < 0))
+ {
+ datum = list_nth(first ?
+ spec->lowerdatums : spec->upperdatums,
+ abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is not equals to %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with splitPartOid).
+ */
+static void
+check_partition_bounds_for_split_list(char *relname, Relation parent,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+
+ /* Should be exists at least one partition for split: */
+ Assert(partdesc->nparts > 0);
+
+ Assert(boundinfo &&
+ boundinfo->strategy == PARTITION_STRATEGY_LIST &&
+ (boundinfo->ndatums > 0 ||
+ partition_bound_accepts_nulls(boundinfo) ||
+ partition_bound_has_default(boundinfo)));
+
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * Function returns "true" in case list of new partitions (partlist) contains
+ * value "value" and "false" if not contains.
+ */
+static bool
+find_value_in_new_partitions(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * Checks that all values of split partition (partOid) contains in new
+ * partitions (partlist).
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Need to check new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(sps->name->relname,
+ parent, sps->bound, splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(sps->name->relname,
+ parent, sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_partitions_not_overlap_range(parent, sps->name, sps->bound,
+ spsPrev->name, spsPrev->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* get_partition_bound_spec
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 855d48372a..0f39312efd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12232,3 +12232,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6c294df786..0ab6daea0b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2028,6 +2028,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 09b028acba..192341c0c3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -392,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 435668fb7c..d496d6ac4b 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index d91032c42a..cbaf030858 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7caf766f0b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1425 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5153c923bf..b975fe295c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6d017f2e91
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,839 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: bounds of partition "sales_feb2022" are outside bounds of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equals to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: new partition "sales_feb2022" would overlap with another (not split) partition "sales_jan2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
I'm sorry, I couldn't answer earlier...
1.
partbounds.c is adding 500+ LOC about checking if proposed partitions
meet the requirements (don't overlap, etc). But a lot of those
checks must already happen, no? Can you re-use/refactor the existing
checks ?
I a bit reduced the number of lines in partbounds.c and added comments.
Unfortunately, it is very difficult to re-use existing checks for other
partitioned tables operations, because mostly part of PostgreSQL
commands works with a single partition.
So for SPLIT/MERGE commands were created new checks for several partitions.
2.
Also, postgres already supports concurrent DDL (CREATE+ATTACH and
DETACH CONCURRENTLY). Is it possible to leverage that ?
(Mostly to reduce the patch size, but also because maybe some cases
could be concurrent?).
Probably "ATTACH CONCURRENTLY" is not supported?
A few words about "DETACH CONCURRENTLY".
"DETACH CONCURRENTLY" can works because this command not move rows
during detach partition (and so no reason to block detached partition).
"DETACH CONCURRENTLY" do not changes data, but changes partition
description (partition is marked as "inhdetachpending = true" etc.).
For SPLIT and MERGE the situation is completely different - these
commands transfer rows between sections.
Therefore partitions must be LOCKED EXCLUSIVELY during rows transfer.
Probably we can use concurrently partitions not participating in SPLIT
and MERGE.
But now PostgreSQL has no possibilities to forbid using a part of
partitions of a partitioned table (until the end of data transfer by
SPLIT/MERGE commands).
Simple locking is not quite suitable here.
I see only one variant of SPLIT/MERGE CONCURRENTLY implementation that
can be realized now:
* ShareUpdateExclusiveLock on partitioned table;
* AccessExclusiveLock on partition(s) which will be deleted and will be
created during SPLIT/MEGRE command;
* transferring data between locked sections; operations with non-blocked
partitions are allowed;
* sessions which want to use partition(s) which will be deleted, waits
on locks;
* finally we release AccessExclusiveLock on partition(s) which will be
deleted and delete them;
* waiting sessions will get errors "relation ... does not exist" (we can
transform it to "relation structure was changed ... please try again"?).
It doesn't look pretty.
Therefore for the SPLIT/MERGE command the partitioned table is locked
with AccessExclusiveLock.
3.
An UPDATE on a partitioned table will move tuples from one partition
to another. Is there a way to re-use that?
This could be realized using methods that are called from
ExecCrossPartitionUpdate().
But using these methods is more expensive than the current
implementation of the SPLIT/MERGE commands.
SPLIT/MERGE commands uses "bulk insert" and there is low overhead for
finding a partition to insert data: for MERGE is not need to search
partition; for SPLIT need to use simple search from several partitions
(listed in the SPLIT command).
Below is a test example.
a. Transferring data from the table "test2" to partitions "partition1"
and "partition2" using the current implementation of tuple routing in
PostgreSQL:
CREATE TABLE test (a int, b char(10)) PARTITION BY RANGE (a);
CREATE TABLE partition1 PARTITION OF test FOR VALUES FROM (10) TO (20);
CREATE TABLE partition2 PARTITION OF test FOR VALUES FROM (20) TO (30);
CREATE TABLE test2 (a int, b char(10));
INSERT INTO test2 (a, b) SELECT 11, 'a' FROM generate_series(1, 1000000);
INSERT INTO test2 (a, b) SELECT 22, 'b' FROM generate_series(1, 1000000);
INSERT INTO test(a, b) SELECT a, b FROM test2;
DROP TABLE test2;
DROP TABLE test;
Three attempts (the results are little different), the best result:
INSERT 0 2000000
Time: 4467,814 ms (00:04,468)
b. Transferring data from the partition "partition0" to partitions
"partition 1" and "partition2" using SPLIT command:
CREATE TABLE test (a int, b char(10)) PARTITION BY RANGE (a);
CREATE TABLE partition0 PARTITION OF test FOR VALUES FROM (0) TO (30);
INSERT INTO test (a, b) SELECT 11, 'a' FROM generate_series(1, 1000000);
INSERT INTO test (a, b) SELECT 22, 'b' FROM generate_series(1, 1000000);
ALTER TABLE test SPLIT PARTITION partition0 INTO
(PARTITION partition0 FOR VALUES FROM (0) TO (10),
PARTITION partition1 FOR VALUES FROM (10) TO (20),
PARTITION partition2 FOR VALUES FROM (20) TO (30));
DROP TABLE test;
Three attempts (the results are little different), the best result:
ALTER TABLE
Time: 3840,127 ms (00:03,840)
So the current implementation of tuple routing is ~16% slower than the
SPLIT command.
That's quite a lot.
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v14-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v14-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From cfb275aa70ddb94037d72416bec8e6693f6355e7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v14 1/2] 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 ++
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 +
14 files changed, 2097 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 845208d662..3e16019f8a 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
@@ -4401,6 +4403,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4822,6 +4828,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);
@@ -5243,6 +5254,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);
@@ -6231,6 +6250,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:
@@ -17645,6 +17666,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17837,23 +17889,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.
@@ -19331,3 +19368,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 9384214942..239d3831df 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
@@ -2260,6 +2260,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2274,6 +2275,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2287,6 +2289,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2303,6 +2320,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -16878,6 +16896,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17460,6 +17479,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 487eb2041b..a14ba6d2d0 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"
@@ -3281,6 +3283,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
@@ -3552,6 +3628,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 29643fb4ab..b5eaf0b7ad 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4983,3 +4983,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 f4ed9bbff9..f9487417de 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -897,6 +897,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
*/
@@ -905,6 +916,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;
@@ -2017,6 +2029,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 957ee18d84..1ab92a2afe 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -313,6 +313,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 a32fc6c149..57804298df 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 5413a59a80..d91032c42a 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/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 9a139f1e24..d1924bb337 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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 2f5802195d..4b010a7d81 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2513,6 +2513,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.31.0.windows.1
v14-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v14-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 17139ca416684b863f6f057cbe856f5e29b8cf99 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v14 2/2] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
15 files changed, 3674 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3e16019f8a..cdc54046f6 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -638,6 +638,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4403,6 +4406,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4828,6 +4835,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5254,6 +5266,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6250,6 +6270,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19369,6 +19391,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19423,6 +19694,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 239d3831df..fa4887c48a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -268,6 +268,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -740,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2250,6 +2253,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2294,6 +2314,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16960,6 +16994,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17555,6 +17590,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index a14ba6d2d0..0dfac06f84 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3283,6 +3283,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3620,7 +3657,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3628,6 +3665,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3636,7 +3674,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4032,13 +4074,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4047,9 +4089,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4057,7 +4099,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b5eaf0b7ad..99659604a5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5046,10 +5046,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5082,6 +5141,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index f3ea36a231..b985b1ff72 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12205,3 +12205,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f9487417de..f3fa4c50ab 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2029,6 +2029,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 1ab92a2afe..63117d5b92 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -392,6 +392,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 57804298df..d8371bdfd6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7d489718a3..ed13a43f53 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index d91032c42a..cbaf030858 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index d1924bb337..8b3876f48d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -127,7 +127,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Implements feature: tested, passed
Spec compliant: tested, passed
Documentation: tested, failed
Feature is clearly missing with partition handling in PostgreSQL, so, this patch is very welcome (as are futur steps)
Code presents good, comments are explicit
Patch v14 apply nicely on 4f46f870fa56fa73d6678273f1bd059fdd93d5e6
Compilation ok with meson compile
LCOV after meson test shows good new code coverage.
Documentation is missing in v14.
Hi!
Documentation: tested, failed
Added documentation (as separate commit).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v15-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v15-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 43c03e2e7f56e45b2ec1dc45c3abd79960e74b1f Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v15 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d4d93eeb7c..a77d7f50aa 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1091,14 +1098,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1341,7 +1433,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1757,6 +1850,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.31.0.windows.1
v15-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v15-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From f9508ebc87ee3e17ba2c1d86bec08b9215d84b0c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v15 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 ++
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 +
14 files changed, 2097 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 c510a01fd8..68533ef53b 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
@@ -4468,6 +4470,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4889,6 +4895,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);
@@ -5276,6 +5287,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);
@@ -6259,6 +6278,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:
@@ -17671,6 +17692,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17863,23 +17915,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.
@@ -19360,3 +19397,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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/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
v15-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v15-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From af8d90580a1e635edf6d3921cb01215effae06fe Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v15 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
15 files changed, 3674 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 68533ef53b..988893a6d0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -638,6 +638,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4470,6 +4473,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4895,6 +4902,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5287,6 +5299,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6278,6 +6298,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19398,6 +19420,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19452,6 +19723,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ad8f68b99d..737b97445d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -268,6 +268,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -740,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2270,6 +2273,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2314,6 +2334,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16987,6 +17021,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17583,6 +17618,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e9fbfc0605..7c0f610548 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3265,6 +3265,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3600,7 +3637,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3608,6 +3645,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3616,7 +3654,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4012,13 +4054,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4027,9 +4069,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4037,7 +4079,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 032ebae595..32f2f9378f 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 4a98b82f07..387de61b51 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12182,3 +12182,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f5c0625bbf..f8031c609e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2138,6 +2138,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 2abe9d7d7d..f855a33261 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -393,6 +393,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 2fe80fb4fc..97e9185579 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 1a42d9f39b..e9b431dd4f 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2a98bccbf6..60e2475ac6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 41fa8e93c5..80608597e5 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
Hi,
Patch v15-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patch
Apply nicely.
One warning on meson compile (configure -Dssl=openssl -Dldap=enabled -Dauto_features=enabled -DPG_TEST_EXTRA='ssl,ldap,kerberos' -Dbsd_auth=disabled -Dbonjour=disabled -Dpam=disabled -Dpltcl=disabled -Dsystemd=disabled -Dzstd=disabled -Db_coverage=true)
../../src/pgmergesplit/src/test/modules/test_ddl_deparse/test_ddl_deparse.c: In function ‘get_altertable_subcmdinfo’:
../../src/pgmergesplit/src/test/modules/test_ddl_deparse/test_ddl_deparse.c:112:17: warning: enumeration value ‘AT_MergePartitions’ not handled in switch [-Wswitch]
112 | switch (subcmd->subtype)
| ^~~~~~
Should be the same with 0002...
meson test perfect, patch coverage is very good.
Patch v15-0002-ALTER-TABLE-SPLIT-PARTITION-command.patch
Doesn't apply on 326a33a289c7ba2dbf45f17e610b7be98dc11f67
Patch v15-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch
Apply with one warning 1 line add space error (translate from french "warning: 1 ligne a ajouté des erreurs d'espace").
v15-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch:54: trailing whitespace.
One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
Comment are ok for me. A non native english speaker.
Perhaps you could add some remarks in ddl.html and alter-ddl.html
Stéphane
The new status of this patch is: Waiting on Author
Thank you!
Corrected version in attachment.
Strange that cfbot didn't show this warning ...
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v16-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v16-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From fa3a3cde9035092ad2812b7353cfbec9cbc29d2c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
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 <name> ATTACH PARTITION <partition-name> 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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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
v16-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v16-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 309944461a902ae5aea8e229991c093de6c36ffc Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v16 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 49e9340d5c..29c29e9d52 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -638,6 +638,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4478,6 +4481,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4903,6 +4910,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5295,6 +5307,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6286,6 +6306,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19426,6 +19448,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19480,6 +19751,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ad8f68b99d..737b97445d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -268,6 +268,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -740,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2270,6 +2273,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2314,6 +2334,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16987,6 +17021,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17583,6 +17618,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e9fbfc0605..7c0f610548 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3265,6 +3265,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3600,7 +3637,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3608,6 +3645,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3616,7 +3654,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4012,13 +4054,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4027,9 +4069,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4037,7 +4079,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 032ebae595..32f2f9378f 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 4a98b82f07..387de61b51 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12182,3 +12182,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f5c0625bbf..f8031c609e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2138,6 +2138,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 2abe9d7d7d..f855a33261 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -393,6 +393,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 2fe80fb4fc..97e9185579 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 1a42d9f39b..e9b431dd4f 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2a98bccbf6..60e2475ac6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 b4171dd382..6b296f81ec 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 41fa8e93c5..80608597e5 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
v16-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v16-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 870b490a7027b87af7408bdb6ee5e002d360cba8 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v16 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d4d93eeb7c..a77d7f50aa 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1091,14 +1098,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1341,7 +1433,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1757,6 +1850,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.31.0.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Implements feature: tested, passed
Spec compliant: tested, passed
Documentation: tested, failed
Hi,
Just a minor warning with documentation patch
git apply ../v16-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch
../v16-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch:54: trailing whitespace.
One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
warning: 1 ligne a ajouté des erreurs d'espace.
(perhaps due to my Ubuntu 22.04.2 french install)
Everything else is ok.
Thanks a lot for your work
Stéphane
Thanks!
I missed the trailing whitespace.
Corrected.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v17-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v17-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From fa3a3cde9035092ad2812b7353cfbec9cbc29d2c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v17 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 <name> ATTACH PARTITION <partition-name> 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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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
v17-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v17-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 309944461a902ae5aea8e229991c093de6c36ffc Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v17 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 49e9340d5c..29c29e9d52 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -638,6 +638,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4478,6 +4481,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4903,6 +4910,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5295,6 +5307,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6286,6 +6306,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19426,6 +19448,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19480,6 +19751,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ad8f68b99d..737b97445d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -268,6 +268,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -740,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2270,6 +2273,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2314,6 +2334,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -16987,6 +17021,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17583,6 +17618,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e9fbfc0605..7c0f610548 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3265,6 +3265,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3600,7 +3637,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3608,6 +3645,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3616,7 +3654,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4012,13 +4054,13 @@ setSchemaName(char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4027,9 +4069,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4037,7 +4079,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 032ebae595..32f2f9378f 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 4a98b82f07..387de61b51 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12182,3 +12182,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f5c0625bbf..f8031c609e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2138,6 +2138,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 2abe9d7d7d..f855a33261 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -393,6 +393,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 2fe80fb4fc..97e9185579 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 1a42d9f39b..e9b431dd4f 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -44,4 +44,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2a98bccbf6..60e2475ac6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 b4171dd382..6b296f81ec 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 41fa8e93c5..80608597e5 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.31.0.windows.1
v17-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v17-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 28c0c7d37fc86e9d2584771813a06281bd72d5f9 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v17 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d4d93eeb7c..1480e30c18 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1091,14 +1098,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1341,7 +1433,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1757,6 +1850,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.31.0.windows.1
This patch no longer applies to master, please submit a rebased version to the
thread. I've marked the CF entry as waiting for author in the meantime.
--
Daniel Gustafsson
Thanks, Daniel!
This patch no longer applies to master, please submit a rebased
version to the thread.
Here is a rebased version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v18-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v18-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From fa9372301410eed180ddead4a3ff595e1acc77bf Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v18 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 fce5e6f220..a62abe128d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -640,6 +640,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
@@ -4493,6 +4495,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4914,6 +4920,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);
@@ -5301,6 +5312,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);
@@ -6284,6 +6303,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:
@@ -17701,6 +17722,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17893,23 +17945,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.
@@ -19394,3 +19431,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 39ab7eac0d..ac8b121f97 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -745,7 +745,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
@@ -2287,6 +2287,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2301,6 +2302,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2314,6 +2316,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2330,6 +2347,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17128,6 +17146,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17724,6 +17743,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 d67580fc77..1cc5048c9e 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"
@@ -3264,6 +3266,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
@@ -3533,6 +3609,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 7c5d9110fb..7e4ab9eca6 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 88b03cc472..6f2c1693b4 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;
@@ -2235,6 +2247,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 f5b2e61ca5..a61b9e922b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -322,6 +322,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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 82f937fca4..216ed3c47f 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 cf46fa3359..6ed44fbbae 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 e941fb6c82..68faaf2606 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2552,6 +2552,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v18-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v18-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 379171c4cd2cee6f49c516ef0f73110ae2e5cd24 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v18 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a62abe128d..0fe9fbe705 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -640,6 +640,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4495,6 +4498,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4920,6 +4927,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5312,6 +5324,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6303,6 +6323,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19432,6 +19454,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19486,6 +19757,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ac8b121f97..01da2ee775 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -642,6 +643,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -760,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2277,6 +2280,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2321,6 +2341,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17211,6 +17245,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17820,6 +17855,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 1cc5048c9e..7aff987204 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -135,7 +135,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3266,6 +3266,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3601,7 +3638,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3609,6 +3646,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3617,7 +3655,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4015,13 +4057,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4030,9 +4072,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4040,7 +4082,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 7e4ab9eca6..8aec8d69ce 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d3a973d86b..1984b244cc 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12606,3 +12606,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6f2c1693b4..ba9e3d9700 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2247,6 +2247,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a61b9e922b..8d7d3c428d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -402,6 +402,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 2fe80fb4fc..97e9185579 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index b006d9d475..0e4a8a4047 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2a98bccbf6..60e2475ac6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 216ed3c47f..324a95b35f 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6ed44fbbae..0b632221b6 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split 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_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v18-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v18-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From d0236d733ca9578183b64b4ed4cc2dfff887c669 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v18 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d4d93eeb7c..1480e30c18 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1091,14 +1098,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1341,7 +1433,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1757,6 +1850,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: not tested
Implements feature: not tested
Spec compliant: not tested
Documentation: not tested
Only documentation patch applied on 4e465aac36ce9a9533c68dbdc83e67579880e628
Checked with v18
The new status of this patch is: Waiting on Author
Thank you, Stephane!
Rebased version attached to email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v19-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v19-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 7a472ec572fb7c83431c153b9e27b54bb2a9493c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v19 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 4dc029f91f..203432dfb1 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -640,6 +640,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
@@ -4492,6 +4494,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_CheckNotNull:
/*
@@ -4913,6 +4919,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);
@@ -5300,6 +5311,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);
@@ -6283,6 +6302,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:
@@ -17698,6 +17719,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 <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -17890,23 +17942,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.
@@ -19398,3 +19435,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 edb6c00ece..cb90f15948 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -742,7 +742,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
@@ -2284,6 +2284,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2298,6 +2299,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2311,6 +2313,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2327,6 +2344,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17125,6 +17143,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17721,6 +17740,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 e48e9e99d3..f23e1e2930 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"
@@ -3258,6 +3260,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
@@ -3527,6 +3603,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 7c5d9110fb..7e4ab9eca6 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 efb5c3e098..712f39f50b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -931,6 +931,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
*/
@@ -939,6 +950,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;
@@ -2234,6 +2246,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 f5b2e61ca5..a61b9e922b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -322,6 +322,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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 82f937fca4..216ed3c47f 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 4df9d8503b..fa02a704c1 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 depends on create_am and cannot run concurrently with
# any test that runs DDL
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 e941fb6c82..68faaf2606 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2552,6 +2552,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v19-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v19-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From c00a16a51ff6cb27594afcf6f15cccaabbe48d8d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v19 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 203432dfb1..07a0266d1b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -640,6 +640,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4494,6 +4497,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -4919,6 +4926,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5311,6 +5323,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6302,6 +6322,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -19436,6 +19458,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -19490,6 +19761,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index cb90f15948..642e019e7b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -642,6 +643,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -757,7 +760,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2274,6 +2277,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2318,6 +2338,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17208,6 +17242,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17817,6 +17852,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index f23e1e2930..8de45df453 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -135,7 +135,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3260,6 +3260,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3595,7 +3632,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3603,6 +3640,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3611,7 +3649,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4009,13 +4051,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4024,9 +4066,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4034,7 +4076,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 7e4ab9eca6..8aec8d69ce 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d3a973d86b..1984b244cc 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12606,3 +12606,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 712f39f50b..00667a7210 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2246,6 +2246,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a61b9e922b..8d7d3c428d 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -402,6 +402,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 2fe80fb4fc..97e9185579 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index b006d9d475..0e4a8a4047 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2a98bccbf6..60e2475ac6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 216ed3c47f..324a95b35f 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fa02a704c1..7f29eef9d6 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v19-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v19-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 818666b451a2306c4af3ce5b40e1f0c9d76d395f Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v19 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d4d93eeb7c..1480e30c18 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1091,14 +1098,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1341,7 +1433,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1757,6 +1850,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Implements feature: tested, passed
Spec compliant: tested, passed
Documentation: tested, passed
It is just a rebase
I check with make and meson
run manual split and merge on list and range partition
Doc fits
The new status of this patch is: Ready for Committer
Rebased version attached to email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v20-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v20-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From dab0c597e8abdb43d7d2c404284ccfcd96b2e443 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v20 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 e456ccd767..f02b8a9dbe 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -650,6 +650,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4679,6 +4681,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5093,6 +5099,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);
@@ -5481,6 +5492,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);
@@ -6467,6 +6486,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:
@@ -18492,6 +18513,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -18684,23 +18736,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(wqueue, 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.
@@ -20242,3 +20279,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 c224df4ecc..242b8c2715 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -743,7 +743,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
@@ -2285,6 +2285,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2299,6 +2300,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2312,6 +2314,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2328,6 +2345,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17257,6 +17275,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17858,6 +17877,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 cf0d432ab1..6c4dc3f1b1 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"
@@ -3378,6 +3380,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
@@ -3648,6 +3724,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 9f207b44c3..213289f515 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 e494309da8..31b6e2ab24 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -924,6 +924,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
*/
@@ -932,6 +943,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;
@@ -2247,6 +2259,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 5984dcfa4b..f76a7c3023 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 53bcc867df..7b95bb73b0 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 0302f79bb7..0bdcd2e617 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 f0987ff537..42cfeab20c 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 depends on create_am and cannot run concurrently with
# any test that runs DDL
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 bf50a32119..5251db5fad 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2563,6 +2563,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v20-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v20-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From e3914255ad86e9bc48507d4a479d35f99267a43d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v20 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f02b8a9dbe..f779d9b62b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -650,6 +650,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4681,6 +4684,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5099,6 +5106,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5492,6 +5504,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6486,6 +6506,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20280,6 +20302,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20334,6 +20605,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 242b8c2715..796ad1c124 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -642,6 +643,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -758,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2275,6 +2278,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2319,6 +2339,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17340,6 +17374,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17954,6 +17989,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6c4dc3f1b1..de1b3a773b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3380,6 +3380,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3716,7 +3753,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3724,6 +3761,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3732,7 +3770,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4137,13 +4179,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4152,9 +4194,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4162,7 +4204,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 213289f515..d64d724099 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index ed7f40f053..26f81a32fa 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12651,3 +12651,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 31b6e2ab24..6acaeccebc 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2259,6 +2259,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f76a7c3023..b54ebbb786 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 7b95bb73b0..67a1f94763 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index b006d9d475..0e4a8a4047 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 0bdcd2e617..f7258968b1 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 42cfeab20c..fb90d988ff 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v20-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v20-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 6f2f3c495453a4af8aaaae3a11108f7c8cebdfa3 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v20 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 2c4138e4e9..17be88a53d 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1092,14 +1099,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1342,7 +1434,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1758,6 +1851,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
Hello!
Added commit v21-0004-SPLIT-PARTITION-optimization.patch.
Three already existing commits did not change
(v21-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patch,
v21-0002-ALTER-TABLE-SPLIT-PARTITION-command.patch,
v21-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch).
The new commit is an optimization for the SPLIT PARTITION command.
Description of optimization:
1) optimization is used for the SPLIT PARTITION command for tables with
BY RANGE partitioning in case the partitioning key has a b-tree index;
2) the point of optimization is that, if after dividing of the old
partition, all its records according to the range conditions must be
inserted into ONE new partition, then instead of transferring data (from
the old partition to new partition), the old partition will be renamed.
Example.
Suppose we have a BY RANGE-partitioned table "test" (indexed by
partitioning key) with a single partition "test_default", which we want
to split into two partitions ("test_1" and "test_default"), and all
records should be moved to the "test_1" partition.
When executing the script below, the "test_default" partition will be
renamed to "test_1".
----
CREATE TABLE test(d date, v text) PARTITION BY RANGE (d);
CREATE TABLE test_default PARTITION OF test DEFAULT;
CREATE INDEX idx_test_d ON test USING btree (d);
INSERT INTO test (d, v)
SELECT d, 'value_' || md5(random()::text) FROM
generate_series('2024-01-01', '2024-01-25', interval '10 seconds')
AS d;
-- Oid of table 'test_default':
SELECT 'test_default'::regclass::oid AS previous_partition_oid;
ALTER TABLE test SPLIT PARTITION test_default INTO
(PARTITION test_1 FOR VALUES FROM ('2024-01-01') TO ('2024-02-01'),
PARTITION test_default DEFAULT);
-- Oid of table 'test_1' (should be the same as "previous_partition_oid"):
SELECT 'test_1'::regclass::oid AS current_partition_oid;
DROP TABLE test CASCADE;
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v21-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v21-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 88f441946c20b93b216261a8856d837eb8920a89 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v21 1/4] 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 7206da7c53..398040f6e0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -650,6 +650,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4676,6 +4678,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5090,6 +5096,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);
@@ -5478,6 +5489,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);
@@ -6464,6 +6483,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:
@@ -18491,6 +18512,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -18683,23 +18735,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(wqueue, 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.
@@ -20241,3 +20278,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 d631ac89a9..fe6c43975c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -743,7 +743,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
@@ -2298,6 +2298,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2312,6 +2313,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2325,6 +2327,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2341,6 +2358,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17284,6 +17302,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17885,6 +17904,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 cf0d432ab1..6c4dc3f1b1 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"
@@ -3378,6 +3380,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
@@ -3648,6 +3724,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 9f207b44c3..213289f515 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 e494309da8..31b6e2ab24 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -924,6 +924,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
*/
@@ -932,6 +943,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;
@@ -2247,6 +2259,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 5984dcfa4b..f76a7c3023 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 53bcc867df..7b95bb73b0 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 0302f79bb7..0bdcd2e617 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 f0987ff537..42cfeab20c 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 depends on create_am and cannot run concurrently with
# any test that runs DDL
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 d659adbfd6..5d6893679d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2568,6 +2568,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v21-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v21-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From ac77b513a2cd18883da84277d76dd29cb165e6d8 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v21 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 398040f6e0..fbe8b7ccdd 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -650,6 +650,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4678,6 +4681,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5096,6 +5103,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5489,6 +5501,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6483,6 +6503,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20279,6 +20301,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20333,6 +20604,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index fe6c43975c..a39f2edbca 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -642,6 +643,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -758,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2288,6 +2291,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2332,6 +2352,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17367,6 +17401,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -17981,6 +18016,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6c4dc3f1b1..de1b3a773b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3380,6 +3380,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3716,7 +3753,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3724,6 +3761,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3732,7 +3770,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4137,13 +4179,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4152,9 +4194,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4162,7 +4204,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 213289f515..d64d724099 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index ed7f40f053..26f81a32fa 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12651,3 +12651,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 31b6e2ab24..6acaeccebc 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2259,6 +2259,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f76a7c3023..b54ebbb786 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 7b95bb73b0..67a1f94763 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index b006d9d475..0e4a8a4047 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 0bdcd2e617..f7258968b1 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_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 42cfeab20c..fb90d988ff 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v21-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v21-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From bc2b618d9445c8d8e84766e625e98e75c1d4d12c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v21 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e1d207bc60..0bb5d2c116 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1092,14 +1099,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1342,7 +1434,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1758,6 +1851,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
v21-0004-SPLIT-PARTITION-optimization.patchtext/plain; charset=UTF-8; name=v21-0004-SPLIT-PARTITION-optimization.patchDownload
From 6742a2532bde1a0fd710aeffc1c4015a4df5f400 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH v21 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 686 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 ++++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 978 insertions(+), 167 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index fbe8b7ccdd..d3f907f119 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20311,20 +20311,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20335,67 +20362,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext * pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
- table_finish_bulk_insert(pc->partRel, ti_options);
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20403,9 +20429,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20413,11 +20438,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20425,41 +20449,261 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ return isSameName;
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
/*
* Create partition context for DEFAULT partition. We can insert values
* into this partition in case spaces with values between new partitions.
*/
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
{
/* Indicate that we allocate context for old DEFAULT partition */
isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
}
- econtext = GetPerTupleExprContext(estate);
+ econtext = GetPerTupleExprContext(si->estate);
/* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
/*
* Map computing for moving attributes of split partition to new partition
* (for first new partition but other new partitions can use the same
* map).
*/
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
RelationGetDescr(pc->partRel));
/* Scan through the rows. */
snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
/*
* Switch to per-tuple memory context and reset it for each tuple
* produced, so we don't leak memory.
*/
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
@@ -20472,7 +20716,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
econtext->ecxt_scantuple = srcslot;
/* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
+ foreach(listptr, si->partContexts)
{
pc = (SplitPartitionContext *) lfirst(listptr);
@@ -20493,7 +20737,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ereport(ERROR,
(errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
+ errtable(si->splitRel)));
}
if (tuple_map)
@@ -20534,74 +20778,208 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ExecDropSingleTupleTableSlot(srcslot);
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
/* Need to close table and free buffers for DEFAULT partition. */
if (isOldDefaultPart)
{
- Relation defaultPartRel = defaultPartCtx->partRel;
+ Relation defaultPartRel = defaultPartCtx->partRel;
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ deleteSplitPartitionContext(defaultPartCtx);
/* Keep the lock until commit. */
table_close(defaultPartRel, NoLock);
}
}
/*
- * createPartitionTable: create table for new partition with given name
- * (newPartName) like table (modelRelName)
+ * findNewPartForSlot: find partition that contains slot value.
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
- * INCLUDING ALL EXCLUDING INDEXES)
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
- AlterTableUtilityContext *context)
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
- 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;
+ econtext = GetPerTupleExprContext(si->estate);
- tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
/*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~CREATE_TABLE_LIKE_INDEXES;
- tlc->relationOid = InvalidOid;
- createStmt->tableElts = lappend(createStmt->tableElts, tlc);
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
- /* 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;
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
- ProcessUtility(wrapper,
- context->queryString,
- false,
- PROCESS_UTILITY_SUBCOMMAND,
- NULL,
- NULL,
- None_Receiver,
- NULL);
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
}
/*
@@ -20613,16 +20991,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -20641,35 +21017,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -20690,8 +21038,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
RenameRelationInternal(splitRelOid, tmpRelName, false, false);
- splitPartName = makeRangeVar(
- get_namespace_name(RelationGetNamespace(splitRel)),
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
tmpRelName, -1);
/*
@@ -20701,43 +21048,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
- /* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
- {
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
- createPartitionTable(sps->name, splitPartName, context);
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+ /* Create new partitions (like split partition), without indexes. */
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
- newPartRels = lappend(newPartRels, newPartRel);
+ if (!pcWithAllRows)
+ {
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
@@ -20883,8 +21235,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RelationGetRelationName(pc->partRel))));
/*
- * Checking that two partitions have the same name was before,
- * in function transformPartitionCmdForMerge().
+ * 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. */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 08bf021796..ece707fdc6 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 58e17f33e8..627977ef30 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
On Mon, 4 Dec 2023 at 13:22, Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hello!
Added commit v21-0004-SPLIT-PARTITION-optimization.patch.
CFBot shows that the patch does not apply anymore as in [1]http://cfbot.cputube.org/patch_46_3659.log:
=== Applying patches on top of PostgreSQL commit ID
8ba6fdf905d0f5aef70ced4504c6ad297bfe08ea ===
=== applying patch ./v21-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patch
patching file src/backend/commands/tablecmds.c
...
Hunk #7 FAILED at 18735.
Hunk #8 succeeded at 20608 (offset 315 lines).
1 out of 8 hunks FAILED -- saving rejects to file
src/backend/commands/tablecmds.c.rej
patching file src/backend/parser/gram.y
Please post an updated version for the same.
[1]: http://cfbot.cputube.org/patch_46_3659.log
Regards,
Vignesh
On 2024-Jan-26, vignesh C wrote:
Please post an updated version for the same.
Here's a rebase. I only fixed the conflicts, didn't review.
--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
Attachments:
v22-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/x-diff; charset=utf-8Download
From d7e99c3e4a1ab543bbdab4807d3ca7c966264393 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v22 1/4] 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 68f658e834..a44a8156cf 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4733,6 +4735,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5158,6 +5164,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);
@@ -5548,6 +5559,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);
@@ -6536,6 +6555,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:
@@ -18812,6 +18833,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19014,23 +19066,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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.
@@ -20584,3 +20621,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 130f7fc7c3..4a5b13c300 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -744,7 +744,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
@@ -2299,6 +2299,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2313,6 +2314,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2326,6 +2328,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2342,6 +2359,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17324,6 +17342,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17925,6 +17944,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 56ac4f516e..884a280869 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"
@@ -3404,6 +3406,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
@@ -3674,6 +3750,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 8a1a5a7255..b3b3aac02a 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 476d55dd24..edfe36bf42 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -924,6 +924,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
*/
@@ -932,6 +943,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;
@@ -2248,6 +2260,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 2331acac09..985474df89 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 1d8a414eea..6f0236d207 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 7e866e3c3d..e827ed0214 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2578,6 +2578,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
base-commit: f7cf9494bad3aef1b2ba1cd84376a1e71797ac50
--
2.39.2
v22-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/x-diff; charset=utf-8Download
From 0b0ca826c64f12c26fcc38d694f3d57aa260d49c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v22 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a44a8156cf..b0d2e4af91 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4735,6 +4738,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5164,6 +5171,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5559,6 +5571,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6555,6 +6575,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20622,6 +20644,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20676,6 +20947,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4a5b13c300..6da1f9a076 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -643,6 +644,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -759,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2289,6 +2292,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2333,6 +2353,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17407,6 +17441,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18021,6 +18056,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 884a280869..c5a794e237 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3406,6 +3406,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3742,7 +3779,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3750,6 +3787,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3758,7 +3796,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4163,13 +4205,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4178,9 +4220,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4188,7 +4230,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b3b3aac02a..e3504bfe26 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b625f471a8..110c267823 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12653,3 +12653,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index edfe36bf42..d0ffa3e9de 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2260,6 +2260,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 985474df89..89e0a5c504 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..08bf021796
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6f0236d207..117d78cb1b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..58e17f33e8
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.39.2
v22-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/x-diff; charset=utf-8Download
From b25c343b4df6aef79d1e804f5c2468a345cb9596 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v22 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9670671107..9fb31df250 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1106,14 +1113,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1356,7 +1448,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1772,6 +1865,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.39.2
v22-0004-SPLIT-PARTITION-optimization.patchtext/x-diff; charset=utf-8Download
From 47ece23cb0f818365e97f923dd2d03e898d8e2a4 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH v22 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 810 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 +++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 1040 insertions(+), 229 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b0d2e4af91..52e8ad2b35 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20654,20 +20654,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20678,67 +20705,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext * pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
- table_finish_bulk_insert(pc->partRel, ti_options);
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20746,9 +20772,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20756,11 +20781,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20768,129 +20792,75 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
- /*
- * Create partition context for DEFAULT partition. We can insert values
- * into this partition in case spaces with values between new partitions.
- */
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
{
- /* Indicate that we allocate context for old DEFAULT partition */
- isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
}
- econtext = GetPerTupleExprContext(estate);
-
- /* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
-
- /*
- * Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
- * map).
- */
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
- RelationGetDescr(pc->partRel));
-
- /* Scan through the rows. */
- snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
-
- /*
- * Switch to per-tuple memory context and reset it for each tuple
- * produced, so we don't leak memory.
- */
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
-
- while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
- {
- bool found = false;
- TupleTableSlot *insertslot;
-
- /* Extract data from old tuple. */
- slot_getallattrs(srcslot);
-
- econtext->ecxt_scantuple = srcslot;
-
- /* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
- {
- pc = (SplitPartitionContext *) lfirst(listptr);
-
- if (pc->partqualstate /* skip DEFAULT partition */ &&
- ExecCheck(pc->partqualstate, econtext))
- {
- found = true;
- break;
- }
- ResetExprContext(econtext);
- }
- if (!found)
- {
- /* Use DEFAULT partition if it exists. */
- if (defaultPartCtx)
- pc = defaultPartCtx;
- else
- ereport(ERROR,
- (errcode(ERRCODE_CHECK_VIOLATION),
- errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
- }
-
- if (tuple_map)
- {
- /* Need to use map for copy attributes. */
- insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
- }
- else
- {
- /* Copy attributes directly. */
- insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
-
- ResetExprContext(econtext);
-
- CHECK_FOR_INTERRUPTS();
- }
-
- MemoryContextSwitchTo(oldCxt);
-
- table_endscan(scan);
- UnregisterSnapshot(snapshot);
-
- if (tuple_map)
- free_conversion_map(tuple_map);
-
- ExecDropSingleTupleTableSlot(srcslot);
-
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
- /* Need to close table and free buffers for DEFAULT partition. */
- if (isOldDefaultPart)
- {
- Relation defaultPartRel = defaultPartCtx->partRel;
-
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
- /* Keep the lock until commit. */
- table_close(defaultPartRel, NoLock);
- }
+ return isSameName;
}
/*
@@ -20947,6 +20917,414 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
+ }
+
+ econtext = GetPerTupleExprContext(si->estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(si->splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * findNewPartForSlot: find partition that contains slot value.
+ *
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
+ */
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
+{
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
+
+ econtext = GetPerTupleExprContext(si->estate);
+
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
+
+ /*
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
+
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
+}
+
/*
* ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
*/
@@ -20956,16 +21334,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -20984,35 +21360,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -21033,8 +21381,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
RenameRelationInternal(splitRelOid, tmpRelName, false, false);
- splitPartName = makeRangeVar(
- get_namespace_name(RelationGetNamespace(splitRel)),
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
tmpRelName, -1);
/*
@@ -21044,43 +21391,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
+
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
+
/* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
+
+ if (!pcWithAllRows)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
-
- createPartitionTable(sps->name, splitPartName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
- newPartRels = lappend(newPartRels, newPartRel);
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
@@ -21226,8 +21578,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RelationGetRelationName(pc->partRel))));
/*
- * Checking that two partitions have the same name was before,
- * in function transformPartitionCmdForMerge().
+ * 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. */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 08bf021796..ece707fdc6 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 58e17f33e8..627977ef30 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.2
On 2024-Jan-26, Alvaro Herrera wrote:
On 2024-Jan-26, vignesh C wrote:
Please post an updated version for the same.
Here's a rebase. I only fixed the conflicts, didn't review.
Hmm, but I got the attached regression.diffs with it. I didn't
investigate further, but it looks like the recent changes to replication
identity for partitioned tables has broken the regression tests.
--
Álvaro Herrera 48°01'N 7°57'E — https://www.EnterpriseDB.com/
"This is what I like so much about PostgreSQL. Most of the surprises
are of the "oh wow! That's cool" Not the "oh shit!" kind. :)"
Scott Marlowe, http://archives.postgresql.org/pgsql-admin/2008-10/msg00152.php
Attachments:
regression.diffstext/plain; charset=utf-8Download
diff -U3 /pgsql/source/master/src/test/regress/expected/partition_split.out /home/alvherre/Code/pgsql-build/master/src/test/regress/results/partition_split.out
--- /pgsql/source/master/src/test/regress/expected/partition_split.out 2024-01-26 14:57:39.549730792 +0100
+++ /home/alvherre/Code/pgsql-build/master/src/test/regress/results/partition_split.out 2024-01-26 15:22:15.007059433 +0100
@@ -777,8 +777,12 @@
-- Create new partition with identity-column:
CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+ERROR: table "salesmans2_5" being attached contains an identity column "salesman_id"
+DETAIL: The new partition may not contain an identity column.
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+ERROR: no partition of relation "salesmans" found for row
+DETAIL: Partition key of the failing row contains (salesman_id) = (2).
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -789,7 +793,7 @@
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
- salesman_id | |
+ salesman_id | a |
salesman_name | |
(2 rows)
@@ -805,8 +809,13 @@
(PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ERROR: partition bound for relation "salesmans2_5" is null
INSERT INTO salesmans (salesman_name) VALUES ('May');
+ERROR: no partition of relation "salesmans" found for row
+DETAIL: Partition key of the failing row contains (salesman_id) = (3).
INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+ERROR: no partition of relation "salesmans" found for row
+DETAIL: Partition key of the failing row contains (salesman_id) = (4).
SELECT * FROM salesmans1_2;
salesman_id | salesman_name
-------------+---------------
@@ -814,23 +823,17 @@
(1 row)
SELECT * FROM salesmans2_3;
- salesman_id | salesman_name
--------------+---------------
- 2 | Ivanov
-(1 row)
-
+ERROR: relation "salesmans2_3" does not exist
+LINE 1: SELECT * FROM salesmans2_3;
+ ^
SELECT * FROM salesmans3_4;
- salesman_id | salesman_name
--------------+---------------
- 3 | May
-(1 row)
-
+ERROR: relation "salesmans3_4" does not exist
+LINE 1: SELECT * FROM salesmans3_4;
+ ^
SELECT * FROM salesmans4_5;
- salesman_id | salesman_name
--------------+---------------
- 4 | Ford
-(1 row)
-
+ERROR: relation "salesmans4_5" does not exist
+LINE 1: SELECT * FROM salesmans4_5;
+ ^
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -841,32 +844,23 @@
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
- salesman_id | |
+ salesman_id | a |
salesman_name | |
(2 rows)
-- New partitions have identity-columns:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
-(2 rows)
-
+ERROR: relation "salesmans2_3" does not exist
+LINE 1: ...FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans...
+ ^
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
-(2 rows)
-
+ERROR: relation "salesmans3_4" does not exist
+LINE 1: ...FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans...
+ ^
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
-(2 rows)
-
+ERROR: relation "salesmans4_5" does not exist
+LINE 1: ...FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans...
+ ^
DROP TABLE salesmans CASCADE;
--
-- Test: split partition with deleted columns
@@ -1121,19 +1115,20 @@
(PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: no owned sequence found
SELECT * FROM sales_list;
salesman_id | salesman_name | sales_state | sales_amount | sales_date
-------------+---------------+----------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
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
4 | Ivanov | Moscow | 750 | 03-04-2022
+ 5 | Deev | Voronezh | 250 | 03-07-2022
6 | Poirot | Kazan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 11 | Muller | Bryansk | 650 | 03-05-2022
12 | Smith | Volgograd | 350 | 03-10-2022
13 | Gandi | Moscow | 150 | 03-08-2022
- 1 | Trump | Magadan | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 14 | Plato | Voronezh | 950 | 03-05-2022
3 | Ford | St. Petersburg | 2000 | 03-05-2022
7 | May | Ukhta | 1200 | 03-06-2022
9 | May | Ukhta | 1200 | 03-11-2022
@@ -1141,21 +1136,13 @@
(14 rows)
SELECT * FROM sales_west;
- 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
-(4 rows)
-
+ERROR: relation "sales_west" does not exist
+LINE 1: SELECT * FROM sales_west;
+ ^
SELECT * FROM sales_east;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 1 | Trump | Magadan | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
-(2 rows)
-
+ERROR: relation "sales_east" does not exist
+LINE 1: SELECT * FROM sales_east;
+ ^
SELECT * FROM sales_nord;
salesman_id | salesman_name | sales_state | sales_amount | sales_date
-------------+---------------+----------------+--------------+------------
@@ -1166,24 +1153,16 @@
(4 rows)
SELECT * FROM sales_central;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 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
-(4 rows)
-
+ERROR: relation "sales_central" does not exist
+LINE 1: SELECT * FROM sales_central;
+ ^
-- Use indexscan for test indexes after split partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central 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)
-
+ERROR: relation "sales_central" does not exist
+LINE 1: SELECT * FROM sales_central WHERE sales_state = 'Moscow';
+ ^
SELECT * FROM sales_list WHERE sales_state = 'Moscow';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
-------------+---------------+-------------+--------------+------------
@@ -1722,3 +1701,6 @@
DROP TABLE test_2colkey CASCADE;
--
DROP SCHEMA partition_split_schema;
+ERROR: cannot drop schema partition_split_schema because other objects depend on it
+DETAIL: table salesmans2_5 depends on schema partition_split_schema
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
git format-patch -4 HEAD -v 23
=============================
Thanks!
I excluded regression test "Test: split partition witch identity column"
from script src/test/regress/sql/partition_split.sql because after
commit [1]https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49 -- With best regards, Dmitry Koval partitions cannot contain identity columns and queries
CREATE TABLE salesmans2_5(salesman_id INT GENERATED ALWAYS AS IDENTITY
PRIMARY KEY, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2)
TO (5);
returns
ERROR: table "salesmans2_5" being attached contains an identity column
"salesman_id"
DETAIL: The new partition may not contain an identity column.
[1]: https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49 -- With best regards, Dmitry Koval
https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v23-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v23-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 3041dee1fa86363dbaed12cde1d38f061f5fda1b Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v23 1/4] 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 68f658e834..a44a8156cf 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4733,6 +4735,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5158,6 +5164,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);
@@ -5548,6 +5559,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);
@@ -6536,6 +6555,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:
@@ -18812,6 +18833,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19014,23 +19066,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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.
@@ -20584,3 +20621,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 130f7fc7c3..4a5b13c300 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -744,7 +744,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
@@ -2299,6 +2299,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2313,6 +2314,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2326,6 +2328,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2342,6 +2359,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17324,6 +17342,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17925,6 +17944,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 56ac4f516e..884a280869 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"
@@ -3404,6 +3406,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
@@ -3674,6 +3750,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 8a1a5a7255..b3b3aac02a 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 476d55dd24..edfe36bf42 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -924,6 +924,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
*/
@@ -932,6 +943,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;
@@ -2248,6 +2260,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 2331acac09..985474df89 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 1d8a414eea..6f0236d207 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 7e866e3c3d..e827ed0214 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2578,6 +2578,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v23-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v23-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 2439724753c8ac6201685a3d34964f9af256aabf Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v23 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1317 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 792 ++++++++++
16 files changed, 3536 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a44a8156cf..b0d2e4af91 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4735,6 +4738,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5164,6 +5171,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5559,6 +5571,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6555,6 +6575,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20622,6 +20644,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20676,6 +20947,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4a5b13c300..6da1f9a076 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -643,6 +644,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -759,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2289,6 +2292,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2333,6 +2353,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17407,6 +17441,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18021,6 +18056,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 884a280869..c5a794e237 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3406,6 +3406,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3742,7 +3779,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3750,6 +3787,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3758,7 +3796,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4163,13 +4205,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4178,9 +4220,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4188,7 +4230,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b3b3aac02a..e3504bfe26 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b625f471a8..110c267823 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12653,3 +12653,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index edfe36bf42..d0ffa3e9de 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2260,6 +2260,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 985474df89..89e0a5c504 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..38736d3e67
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1317 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6f0236d207..117d78cb1b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..e33e616230
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,792 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v23-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v23-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 383fdf8857a9d36bd5350c06d0dfbbe02499504c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v23 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9670671107..9fb31df250 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1106,14 +1113,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1356,7 +1448,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1772,6 +1865,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
v23-0004-SPLIT-PARTITION-optimization.patchtext/plain; charset=UTF-8; name=v23-0004-SPLIT-PARTITION-optimization.patchDownload
From d1dd3629e2817ee4d60ce12a0fde5ea9bdaecee0 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH v23 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 686 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 ++++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 978 insertions(+), 167 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b0d2e4af91..52e8ad2b35 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20654,20 +20654,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20678,67 +20705,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext * pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
- table_finish_bulk_insert(pc->partRel, ti_options);
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20746,9 +20772,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20756,11 +20781,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20768,41 +20792,261 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ return isSameName;
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
/*
* Create partition context for DEFAULT partition. We can insert values
* into this partition in case spaces with values between new partitions.
*/
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
{
/* Indicate that we allocate context for old DEFAULT partition */
isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
}
- econtext = GetPerTupleExprContext(estate);
+ econtext = GetPerTupleExprContext(si->estate);
/* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
/*
* Map computing for moving attributes of split partition to new partition
* (for first new partition but other new partitions can use the same
* map).
*/
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
RelationGetDescr(pc->partRel));
/* Scan through the rows. */
snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
/*
* Switch to per-tuple memory context and reset it for each tuple
* produced, so we don't leak memory.
*/
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
@@ -20815,7 +21059,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
econtext->ecxt_scantuple = srcslot;
/* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
+ foreach(listptr, si->partContexts)
{
pc = (SplitPartitionContext *) lfirst(listptr);
@@ -20836,7 +21080,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ereport(ERROR,
(errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
+ errtable(si->splitRel)));
}
if (tuple_map)
@@ -20877,74 +21121,208 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ExecDropSingleTupleTableSlot(srcslot);
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
/* Need to close table and free buffers for DEFAULT partition. */
if (isOldDefaultPart)
{
- Relation defaultPartRel = defaultPartCtx->partRel;
+ Relation defaultPartRel = defaultPartCtx->partRel;
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ deleteSplitPartitionContext(defaultPartCtx);
/* Keep the lock until commit. */
table_close(defaultPartRel, NoLock);
}
}
/*
- * createPartitionTable: create table for new partition with given name
- * (newPartName) like table (modelRelName)
+ * findNewPartForSlot: find partition that contains slot value.
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
- * INCLUDING ALL EXCLUDING INDEXES)
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
- AlterTableUtilityContext *context)
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
- 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;
+ econtext = GetPerTupleExprContext(si->estate);
- tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
/*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~CREATE_TABLE_LIKE_INDEXES;
- tlc->relationOid = InvalidOid;
- createStmt->tableElts = lappend(createStmt->tableElts, tlc);
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
- /* 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;
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
- ProcessUtility(wrapper,
- context->queryString,
- false,
- PROCESS_UTILITY_SUBCOMMAND,
- NULL,
- NULL,
- None_Receiver,
- NULL);
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
}
/*
@@ -20956,16 +21334,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -20984,35 +21360,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -21033,8 +21381,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
RenameRelationInternal(splitRelOid, tmpRelName, false, false);
- splitPartName = makeRangeVar(
- get_namespace_name(RelationGetNamespace(splitRel)),
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
tmpRelName, -1);
/*
@@ -21044,43 +21391,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
- /* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
- {
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
- createPartitionTable(sps->name, splitPartName, context);
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+ /* Create new partitions (like split partition), without indexes. */
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
- newPartRels = lappend(newPartRels, newPartRel);
+ if (!pcWithAllRows)
+ {
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
@@ -21226,8 +21578,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RelationGetRelationName(pc->partRel))));
/*
- * Checking that two partitions have the same name was before,
- * in function transformPartitionCmdForMerge().
+ * 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. */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 38736d3e67..4627a91e57 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1314,4 +1314,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index e33e616230..0208c0158c 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -788,5 +788,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
I thought it's wrong to exclude the IDENTITY-column test, so I fixed the
test and return it back.
Changes in attachment (commit
v24-0002-ALTER-TABLE-SPLIT-PARTITION-command.patch).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v24-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v24-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 3041dee1fa86363dbaed12cde1d38f061f5fda1b Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v24 1/4] 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 68f658e834..a44a8156cf 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4733,6 +4735,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5158,6 +5164,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);
@@ -5548,6 +5559,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);
@@ -6536,6 +6555,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:
@@ -18812,6 +18833,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19014,23 +19066,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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.
@@ -20584,3 +20621,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 130f7fc7c3..4a5b13c300 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -744,7 +744,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
@@ -2299,6 +2299,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2313,6 +2314,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2326,6 +2328,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2342,6 +2359,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17324,6 +17342,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17925,6 +17944,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 56ac4f516e..884a280869 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"
@@ -3404,6 +3406,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
@@ -3674,6 +3750,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 8a1a5a7255..b3b3aac02a 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 476d55dd24..edfe36bf42 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -924,6 +924,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
*/
@@ -932,6 +943,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;
@@ -2248,6 +2260,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 2331acac09..985474df89 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 1d8a414eea..6f0236d207 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 7e866e3c3d..e827ed0214 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2578,6 +2578,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v24-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v24-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 1db0a789f5b714ff6096d0aee043bfc081c2d552 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v24 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a44a8156cf..b0d2e4af91 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -662,6 +662,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4735,6 +4738,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5164,6 +5171,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5559,6 +5571,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6555,6 +6575,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20622,6 +20644,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20676,6 +20947,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4a5b13c300..6da1f9a076 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -643,6 +644,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -759,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2289,6 +2292,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2333,6 +2353,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17407,6 +17441,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18021,6 +18056,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 884a280869..c5a794e237 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3406,6 +3406,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3742,7 +3779,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3750,6 +3787,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3758,7 +3796,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4163,13 +4205,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4178,9 +4220,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4188,7 +4230,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b3b3aac02a..e3504bfe26 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b625f471a8..110c267823 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12653,3 +12653,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index edfe36bf42..d0ffa3e9de 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2260,6 +2260,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 985474df89..89e0a5c504 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7eb52f6fee
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6f0236d207..117d78cb1b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..40c71889b6
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v24-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v24-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From ad6223192d8f216fc80a7b687e86ea5a15ac4d67 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v24 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9670671107..9fb31df250 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1106,14 +1113,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1356,7 +1448,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1772,6 +1865,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
v24-0004-SPLIT-PARTITION-optimization.patchtext/plain; charset=UTF-8; name=v24-0004-SPLIT-PARTITION-optimization.patchDownload
From 93d21a2b789b1cd75a27017a4645a6dd10b6ec87 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH v24 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 686 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 ++++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 978 insertions(+), 167 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b0d2e4af91..52e8ad2b35 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20654,20 +20654,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20678,67 +20705,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext * pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
- table_finish_bulk_insert(pc->partRel, ti_options);
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20746,9 +20772,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20756,11 +20781,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20768,41 +20792,261 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ return isSameName;
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
/*
* Create partition context for DEFAULT partition. We can insert values
* into this partition in case spaces with values between new partitions.
*/
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
{
/* Indicate that we allocate context for old DEFAULT partition */
isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
}
- econtext = GetPerTupleExprContext(estate);
+ econtext = GetPerTupleExprContext(si->estate);
/* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
/*
* Map computing for moving attributes of split partition to new partition
* (for first new partition but other new partitions can use the same
* map).
*/
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
RelationGetDescr(pc->partRel));
/* Scan through the rows. */
snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
/*
* Switch to per-tuple memory context and reset it for each tuple
* produced, so we don't leak memory.
*/
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
@@ -20815,7 +21059,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
econtext->ecxt_scantuple = srcslot;
/* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
+ foreach(listptr, si->partContexts)
{
pc = (SplitPartitionContext *) lfirst(listptr);
@@ -20836,7 +21080,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ereport(ERROR,
(errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
+ errtable(si->splitRel)));
}
if (tuple_map)
@@ -20877,74 +21121,208 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ExecDropSingleTupleTableSlot(srcslot);
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
/* Need to close table and free buffers for DEFAULT partition. */
if (isOldDefaultPart)
{
- Relation defaultPartRel = defaultPartCtx->partRel;
+ Relation defaultPartRel = defaultPartCtx->partRel;
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ deleteSplitPartitionContext(defaultPartCtx);
/* Keep the lock until commit. */
table_close(defaultPartRel, NoLock);
}
}
/*
- * createPartitionTable: create table for new partition with given name
- * (newPartName) like table (modelRelName)
+ * findNewPartForSlot: find partition that contains slot value.
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
- * INCLUDING ALL EXCLUDING INDEXES)
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
- AlterTableUtilityContext *context)
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
- 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;
+ econtext = GetPerTupleExprContext(si->estate);
- tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
/*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~CREATE_TABLE_LIKE_INDEXES;
- tlc->relationOid = InvalidOid;
- createStmt->tableElts = lappend(createStmt->tableElts, tlc);
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
- /* 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;
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
- ProcessUtility(wrapper,
- context->queryString,
- false,
- PROCESS_UTILITY_SUBCOMMAND,
- NULL,
- NULL,
- None_Receiver,
- NULL);
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
}
/*
@@ -20956,16 +21334,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -20984,35 +21360,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -21033,8 +21381,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
RenameRelationInternal(splitRelOid, tmpRelName, false, false);
- splitPartName = makeRangeVar(
- get_namespace_name(RelationGetNamespace(splitRel)),
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
tmpRelName, -1);
/*
@@ -21044,43 +21391,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
- /* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
- {
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
- createPartitionTable(sps->name, splitPartName, context);
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+ /* Create new partitions (like split partition), without indexes. */
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
- newPartRels = lappend(newPartRels, newPartRel);
+ if (!pcWithAllRows)
+ {
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
@@ -21226,8 +21578,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RelationGetRelationName(pc->partRel))));
/*
- * Checking that two partitions have the same name was before,
- * in function transformPartitionCmdForMerge().
+ * 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. */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 7eb52f6fee..a8f3d8d6d1 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 40c71889b6..17341353e0 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
On 26 Jan 2024, at 23:36, Dmitry Koval <d.koval@postgrespro.ru> wrote:
<v24-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patch><v24-0002-ALTER-TABLE-SPLIT-PARTITION-command.patch><v24-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patch><v24-0004-SPLIT-PARTITION-optimization.patch>
The CF entry was in Ready for Committer state no so long ago.
Stephane, you might want to review recent version after it was rebased on current HEAD. CFbot's test passed successfully.
Thanks!
Best regards, Andrey Borodin.
Hi!
Rebased version attached to email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v25-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v25-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 1fc70b393481c4b48e22ac5066598935b3882eea Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v25 1/4] 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 7014be8039..c392765a06 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -659,6 +659,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4730,6 +4732,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5155,6 +5161,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);
@@ -5545,6 +5556,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);
@@ -6533,6 +6552,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:
@@ -18823,6 +18844,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19025,23 +19077,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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.
@@ -20595,3 +20632,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 <newPartName> (LIKE <modelRelName>
+ * 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+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 c6e2f679fd..a6d6c54f36 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -745,7 +745,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
@@ -2300,6 +2300,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2314,6 +2315,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2327,6 +2329,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2343,6 +2360,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17330,6 +17348,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PLANS
@@ -17931,6 +17950,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 c7efd8d8ce..48a23c7ca4 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3..9ed80d721e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 2380821600..890bdd2068 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;
@@ -2259,6 +2271,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 2331acac09..985474df89 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -324,6 +324,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 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 b2be88ead1..1071256182 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 1d8a414eea..6f0236d207 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 a3052a181d..6e3e105824 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2583,6 +2583,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v25-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v25-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 9c1b32a25101c0f1039afb9ff53192956ee121f7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v25 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 407 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 655 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
16 files changed, 3677 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index c392765a06..122189cb48 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -659,6 +659,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4732,6 +4735,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5161,6 +5168,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5556,6 +5568,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6552,6 +6572,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20633,6 +20655,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20687,6 +20958,142 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(
+ get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* Struct with context of merged partition
*/
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a6d6c54f36..7cf5e6d55f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -644,6 +645,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -760,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2290,6 +2293,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2334,6 +2354,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17413,6 +17447,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18027,6 +18062,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca4..88a4a41186 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721e..8537759a21 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,602 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec * *parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = -1;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ i++;
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ continue;
+ }
+ new_parts[nparts++] = sps;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec * *)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2a1ee69970..6f113dab6c 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -12650,3 +12650,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 890bdd2068..a69b3dc5bf 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2271,6 +2271,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 985474df89..89e0a5c504 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -404,6 +404,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 1071256182..79b730fb86 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7eb52f6fee
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6f0236d207..117d78cb1b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..40c71889b6
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v25-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v25-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 9559b70ad33a6fdde41c4dbbbb923d7c7f779021 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v25 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 96e3d77605..26c8722d3b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1108,14 +1115,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1358,7 +1450,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1774,6 +1867,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
v25-0004-SPLIT-PARTITION-optimization.patchtext/plain; charset=UTF-8; name=v25-0004-SPLIT-PARTITION-optimization.patchDownload
From 13210c3a8dd7fe6df976888ab6fe3929f832bf81 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH v25 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 686 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 ++++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 978 insertions(+), 167 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 122189cb48..3a5b0007fd 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20665,20 +20665,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20689,67 +20716,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext * pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext * pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
- table_finish_bulk_insert(pc->partRel, ti_options);
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20757,9 +20783,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20767,11 +20792,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20779,41 +20803,261 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ return isSameName;
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * 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);
+}
+
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
/*
* Create partition context for DEFAULT partition. We can insert values
* into this partition in case spaces with values between new partitions.
*/
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
{
/* Indicate that we allocate context for old DEFAULT partition */
isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
}
- econtext = GetPerTupleExprContext(estate);
+ econtext = GetPerTupleExprContext(si->estate);
/* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
/*
* Map computing for moving attributes of split partition to new partition
* (for first new partition but other new partitions can use the same
* map).
*/
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
RelationGetDescr(pc->partRel));
/* Scan through the rows. */
snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
/*
* Switch to per-tuple memory context and reset it for each tuple
* produced, so we don't leak memory.
*/
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
@@ -20826,7 +21070,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
econtext->ecxt_scantuple = srcslot;
/* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
+ foreach(listptr, si->partContexts)
{
pc = (SplitPartitionContext *) lfirst(listptr);
@@ -20847,7 +21091,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ereport(ERROR,
(errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
+ errtable(si->splitRel)));
}
if (tuple_map)
@@ -20888,74 +21132,208 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ExecDropSingleTupleTableSlot(srcslot);
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
/* Need to close table and free buffers for DEFAULT partition. */
if (isOldDefaultPart)
{
- Relation defaultPartRel = defaultPartCtx->partRel;
+ Relation defaultPartRel = defaultPartCtx->partRel;
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ deleteSplitPartitionContext(defaultPartCtx);
/* Keep the lock until commit. */
table_close(defaultPartRel, NoLock);
}
}
/*
- * createPartitionTable: create table for new partition with given name
- * (newPartName) like table (modelRelName)
+ * findNewPartForSlot: find partition that contains slot value.
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
- * INCLUDING ALL EXCLUDING INDEXES)
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
- AlterTableUtilityContext *context)
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
- 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;
+ econtext = GetPerTupleExprContext(si->estate);
- tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
/*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~CREATE_TABLE_LIKE_INDEXES;
- tlc->relationOid = InvalidOid;
- createStmt->tableElts = lappend(createStmt->tableElts, tlc);
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
- /* 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;
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
- ProcessUtility(wrapper,
- context->queryString,
- false,
- PROCESS_UTILITY_SUBCOMMAND,
- NULL,
- NULL,
- None_Receiver,
- NULL);
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
}
/*
@@ -20967,16 +21345,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -20995,35 +21371,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -21044,8 +21392,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
RenameRelationInternal(splitRelOid, tmpRelName, false, false);
- splitPartName = makeRangeVar(
- get_namespace_name(RelationGetNamespace(splitRel)),
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
tmpRelName, -1);
/*
@@ -21055,43 +21402,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
- /* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
- {
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
- createPartitionTable(sps->name, splitPartName, context);
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+ /* Create new partitions (like split partition), without indexes. */
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
- newPartRels = lappend(newPartRels, newPartRel);
+ if (!pcWithAllRows)
+ {
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
@@ -21237,8 +21589,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RelationGetRelationName(pc->partRel))));
/*
- * Checking that two partitions have the same name was before,
- * in function transformPartitionCmdForMerge().
+ * 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. */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 7eb52f6fee..a8f3d8d6d1 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 40c71889b6..17341353e0 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: tested, failed
Implements feature: not tested
Spec compliant: not tested
Documentation: not tested
Hi,
I have failing tap test after patches apply:
ok 201 + partition_merge 2635 ms
not ok 202 + partition_split 5719 ms
@@ -805,6 +805,7 @@
(PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ERROR: no owned sequence found
INSERT INTO salesmans (salesman_name) VALUES ('May');
INSERT INTO salesmans (salesman_name) VALUES ('Ford');
SELECT * FROM salesmans1_2;
@@ -814,23 +815,17 @@
(1 row)
SELECT * FROM salesmans2_3;
- salesman_id | salesman_name
--------------+---------------
- 2 | Ivanov
-(1 row)
-
+ERROR: relation "salesmans2_3" does not exist
+LINE 1: SELECT * FROM salesmans2_3;
The new status of this patch is: Waiting on Author
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Implements feature: not tested
Spec compliant: not tested
Documentation: not tested
Sorry, tests passed when applying all patches.
I planned to check without optimisation first.
The new status of this patch is: Needs review
Hi!
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Thanks for info!
I was unable to reproduce the problem and I wanted to ask for
clarification. But your message was ahead of my question.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Tue, Sep 20, 2022 at 3:21 PM Robert Haas <robertmhaas@gmail.com> wrote:
On Mon, Sep 19, 2022 at 4:42 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thanks for comments and advice!
I thought about this problem and discussed about it with colleagues.
Unfortunately, I don't know of a good general solution.Yeah, me neither.
But for specific situation like this (certain partition is not changing)
we can add CONCURRENTLY modifier.
Our DDL query can be likeALTER TABLE...SPLIT PARTITION [CONCURRENTLY];
With CONCURRENTLY modifier we can lock partitioned table in
ShareUpdateExclusiveLock mode and split partition - in
AccessExclusiveLock mode. So we don't lock partitioned table in
AccessExclusiveLock mode and can modify other partitions during SPLIT
operation (except split partition).
If smb try to modify split partition, he will receive error "relation
does not exist" at end of operation (because split partition will be drop).I think that a built-in DDL command can't really assume that the user
won't modify anything. You'd have to take a ShareLock.But you might be able to have a CONCURRENTLY variant of the command
that does the same kind of multi-transaction thing as, e.g., CREATE
INDEX CONCURRENTLY. You would probably have to be quite careful about
race conditions (e.g. you commit the first transaction and before you
start the second one, someone drops or detaches the partition you were
planning to merge or split). Might take some thought, but feels
possibly doable. I've never been excited enough about this kind of
thing to want to put a lot of energy into engineering it, because
doing it "manually" feels so much nicer to me, and doubly so given
that we now have ATTACH CONCURRENTLY and DETACH CONCURRENTLY, but it
does seem like a thing some people would probably use and value.
+1
Currently people are using external tools to implement this kind of
task. However, having this functionality in core would be great.
Implementing concurrent merge/split seems quite a difficult task,
which needs careful design. It might be too hard to carry around the
syntax altogether. So, I think having basic syntax in-core is a good
step forward. But I think we need a clear notice in the documentation
about the concurrency to avoid wrong user expectations.
------
Regards,
Alexander Korotkov
On Tue, Mar 19, 2024 at 4:43 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thanks for info!
I was unable to reproduce the problem and I wanted to ask for
clarification. But your message was ahead of my question.
I've revised the patchset. I mostly did some refactoring, code
improvements and wrote new comments.
If I apply just the first two patches, I get the same error as [1].
This error happens when createPartitionTable() tries to copy the
identity of another partition. I've fixed that by skipping a copy of
the identity of another partition (remove CREATE_TABLE_LIKE_IDENTITY
from TableLikeClause.options). BTW, the same error happened to me
when I manually ran CREATE TABLE ... (LIKE ... INCLUDING IDENTITY) for
a partition of the table with identity. So, this probably deserves a
separate fix, but I think not directly related to this patch.
I have one question. When merging partitions you're creating a merged
partition like the parent table. But when splitting a partition
you're creating new partitions like the partition being split. What
motivates this difference?
Links.
1. /messages/by-id/171085360143.2046436.7217841141682511557.pgcf@coridan.postgresql.org
------
Regards,
Alexander Korotkov
Attachments:
0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME-v26.patchapplication/octet-stream; name=0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME-v26.patchDownload
From 6344afb8ff139037f3258835bc86df5371d62a7e Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH 3/4] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 124 +++++++++++++++++++++++++++++-
1 file changed, 121 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef8..35a0d914917 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1125,99 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form split a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is DEFAULT partition, one of new partitions must be DEFAULT.
+ In case one of new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contains DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1460,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1877,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.39.3 (Apple Git-145)
0004-SPLIT-PARTITION-optimization-v26.patchapplication/octet-stream; name=0004-SPLIT-PARTITION-optimization-v26.patchDownload
From 4ac9d761f197508dba213265259b86a859989db7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 26 Oct 2023 03:35:24 +0300
Subject: [PATCH 4/4] SPLIT PARTITION optimization
---
src/backend/commands/tablecmds.c | 677 +++++++++++++-----
src/test/regress/expected/partition_split.out | 307 ++++++++
src/test/regress/sql/partition_split.sql | 152 ++++
3 files changed, 974 insertions(+), 162 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ef944e3733b..8d45851c3b7 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20876,20 +20876,47 @@ typedef struct SplitPartitionContext
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot; /* slot for insert row into partition */
Relation partRel; /* relation for partition */
+ SinglePartitionSpec *sps; /* info about single partition (from SQL
+ * command) */
} SplitPartitionContext;
+/*
+ * Struct with context of SPLIT PARTITION operation
+ */
+typedef struct SplitInfo
+{
+ PartitionCmd *cmd; /* SPLIT PARTITION command info */
+
+ Relation rel; /* partitioned table */
+ Relation splitRel; /* split partition */
+
+ Oid defaultPartOid; /* identifier of DEFAULT-partition in rel (if
+ * exists) */
+ List *partContexts; /* list of structs SplitPartitionContext (each
+ * struct for each new partition) */
+ SplitPartitionContext *defaultPartCtx; /* pointer to DEFAULT-partition in
+ * partContexts list (if exists) */
+ EState *estate; /* working state */
+} SplitInfo;
/*
- * createSplitPartitionContext: create context for partition and fill it
+ * createSplitPartitionContext: create context for partition
*/
static SplitPartitionContext *
-createSplitPartitionContext(Relation partRel)
+createSplitPartitionContext(SinglePartitionSpec * sps)
{
- SplitPartitionContext *pc;
+ SplitPartitionContext *pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
- pc->partRel = partRel;
+ pc->sps = sps;
+ return pc;
+}
+/*
+ * fillSplitPartitionContext: fill partition context
+ */
+static void
+fillSplitPartitionContext(SplitPartitionContext * pc)
+{
/*
* Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
* don't bother using it.
@@ -20900,67 +20927,66 @@ createSplitPartitionContext(Relation partRel)
pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
table_slot_callbacks(pc->partRel));
ExecStoreAllNullTuple(pc->dstslot);
-
- return pc;
}
/*
* deleteSplitPartitionContext: delete context for partition
*/
static void
-deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+deleteSplitPartitionContext(SplitPartitionContext *pc)
{
- ExecDropSingleTupleTableSlot(pc->dstslot);
- FreeBulkInsertState(pc->bistate);
+ if (pc->dstslot)
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+
+ if (pc->bistate)
+ {
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
- table_finish_bulk_insert(pc->partRel, ti_options);
+ FreeBulkInsertState(pc->bistate);
+ table_finish_bulk_insert(pc->partRel, ti_options);
+ }
pfree(pc);
}
/*
- * moveSplitTableRows: scan split partition (splitRel) of partitioned table
- * (rel) and move rows into new partitions.
+ * createSplitInfo: create SPLIT PARTITION command context, contexts for new
+ * partitions and generate constraints for them.
+ * We need to use constraints for optimization.
*
- * New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * cmd: SPLIT PARTITION command info.
+ * rel: partitioned table.
+ * splitRel: split partition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
-static void
-moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+static SplitInfo *
+createSplitInfo(PartitionCmd *cmd, Relation rel, Relation splitRel,
+ Oid defaultPartOid)
{
- /* The FSM is empty, so don't bother using it. */
- int ti_options = TABLE_INSERT_SKIP_FSM;
- CommandId mycid;
- EState *estate;
- ListCell *listptr,
- *listptr2;
- TupleTableSlot *srcslot;
- ExprContext *econtext;
- TableScanDesc scan;
- Snapshot snapshot;
- MemoryContext oldCxt;
List *partContexts = NIL;
- TupleConversionMap *tuple_map;
- SplitPartitionContext *defaultPartCtx = NULL,
- *pc;
- bool isOldDefaultPart = false;
+ SplitInfo *si;
+ ListCell *listptr;
- mycid = GetCurrentCommandId(true);
+ si = (SplitInfo *) palloc0(sizeof(SplitInfo));
- estate = CreateExecutorState();
+ si->cmd = cmd;
+ si->rel = rel;
+ si->splitRel = splitRel;
- forboth(listptr, partlist, listptr2, newPartRels)
+ si->defaultPartOid = defaultPartOid;
+ si->estate = CreateExecutorState();
+
+ /* Create context for each new partition and fill it. */
+ foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+ SplitPartitionContext *pc = createSplitPartitionContext(sps);
if (sps->bound->is_default)
{
/* We should not create constraint for detached DEFAULT partition. */
- defaultPartCtx = pc;
+ si->defaultPartCtx = pc;
}
else
{
@@ -20968,9 +20994,8 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/* Build expression execution states for partition check quals. */
partConstraint = get_qual_from_partbound(rel, sps->bound);
- partConstraint =
- (List *) eval_const_expressions(NULL,
- (Node *) partConstraint);
+ partConstraint = (List *) eval_const_expressions(NULL, (Node *) partConstraint);
+
/* Make boolean expression for ExecCheck(). */
partConstraint = list_make1(make_ands_explicit(partConstraint));
@@ -20978,11 +21003,10 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Map the vars in the constraint expression from rel's attnos to
* splitRel's.
*/
- partConstraint = map_partition_varattnos(partConstraint,
- 1, splitRel, rel);
+ partConstraint = map_partition_varattnos(partConstraint, 1, splitRel, rel);
pc->partqualstate =
- ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ ExecPrepareExpr((Expr *) linitial(partConstraint), si->estate);
Assert(pc->partqualstate != NULL);
}
@@ -20990,41 +21014,261 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
partContexts = lappend(partContexts, pc);
}
+ si->partContexts = partContexts;
+
+ return si;
+}
+
+/*
+ * deleteSplitInfo: delete SPLIT PARTITION command context
+ */
+static void
+deleteSplitInfo(SplitInfo * si)
+{
+ ListCell *listptr;
+
+ FreeExecutorState(si->estate);
+
+ foreach(listptr, si->partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
+ pfree(si);
+}
+
+/*
+ * checkNewPartitions: simple check of the new partitions.
+ *
+ * cmd: SPLIT PARTITION command info.
+ * splitRelOid: split partition Oid.
+ *
+ * Returns true if one of the new partitions has the same name as the split
+ * partition.
+ */
+static bool
+checkNewPartitions(PartitionCmd *cmd, Oid splitRelOid)
+{
+ Oid namespaceId;
+ ListCell *listptr;
+ bool isSameName = false;
+ char relname[NAMEDATALEN];
+
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ return isSameName;
+}
+
+/*
+ * createPartitionTable: create table for new partition with given name
+ * (newPartName) like table (modelRelName)
+ *
+ * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * createNewPartitions: simple check of the new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ * splitName: split partition name.
+ * pcWithAllRows: context of partition that contains all the rows of the split
+ * partition or NULL if no such partition exists.
+ *
+ * Function returns name of split partition (and can change it in case of
+ * optimization with split partition renaming).
+ */
+static RangeVar *
+createNewPartitions(SplitInfo * si, RangeVar *splitName,
+ SplitPartitionContext * pcWithAllRows,
+ AlterTableUtilityContext *context)
+{
+ ListCell *listptr;
+ Oid splitRelOid;
+ RangeVar *splitPartName = splitName;
+
+ splitRelOid = RelationGetRelid(si->splitRel);
+
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc == pcWithAllRows)
+ {
+ /* Need to reuse splitRel for partition instead of creation. */
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Rename split partition to new partition.
+ */
+ RenameRelationInternal(splitRelOid, pc->sps->name->relname, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(si->splitRel)),
+ pc->sps->name->relname, -1);
+
+ /*
+ * We must bump the command counter to make the split partition
+ * tuple visible after rename.
+ */
+ CommandCounterIncrement();
+
+ pc->partRel = si->splitRel;
+ /* No need to open relation : splitRel is already opened. */
+ }
+ else
+ {
+ createPartitionTable(pc->sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ pc->partRel = table_openrv(pc->sps->name, AccessExclusiveLock);
+ }
+ }
+
+ return splitPartName;
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * si: SPLIT PARTITION command context.
+ */
+static void
+moveSplitTableRows(SplitInfo * si)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ ListCell *listptr;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *pc = NULL;
+ bool isOldDefaultPart = false;
+ SplitPartitionContext *defaultPartCtx = si->defaultPartCtx;
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare new partitions contexts for insert rows. */
+ foreach(listptr, si->partContexts)
+ fillSplitPartitionContext((SplitPartitionContext *) lfirst(listptr));
+
/*
* Create partition context for DEFAULT partition. We can insert values
* into this partition in case spaces with values between new partitions.
*/
- if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ if (!defaultPartCtx && OidIsValid(si->defaultPartOid))
{
/* Indicate that we allocate context for old DEFAULT partition */
isOldDefaultPart = true;
- defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ defaultPartCtx = createSplitPartitionContext(NULL);
+ defaultPartCtx->partRel = table_open(si->defaultPartOid, AccessExclusiveLock);
+ fillSplitPartitionContext(defaultPartCtx);
}
- econtext = GetPerTupleExprContext(estate);
+ econtext = GetPerTupleExprContext(si->estate);
/* Create necessary tuple slot. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
- table_slot_callbacks(splitRel));
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(si->splitRel),
+ table_slot_callbacks(si->splitRel));
/*
* Map computing for moving attributes of split partition to new partition
* (for first new partition but other new partitions can use the same
* map).
*/
- pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
- tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ pc = (SplitPartitionContext *) lfirst(list_head(si->partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(si->splitRel),
RelationGetDescr(pc->partRel));
/* Scan through the rows. */
snapshot = RegisterSnapshot(GetLatestSnapshot());
- scan = table_beginscan(splitRel, snapshot, 0, NULL);
+ scan = table_beginscan(si->splitRel, snapshot, 0, NULL);
/*
* Switch to per-tuple memory context and reset it for each tuple
* produced, so we don't leak memory.
*/
- oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
@@ -21037,7 +21281,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
econtext->ecxt_scantuple = srcslot;
/* Search partition for current slot srcslot. */
- foreach(listptr, partContexts)
+ foreach(listptr, si->partContexts)
{
pc = (SplitPartitionContext *) lfirst(listptr);
@@ -21058,7 +21302,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ereport(ERROR,
(errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
- errtable(splitRel)));
+ errtable(si->splitRel)));
}
if (tuple_map)
@@ -21099,74 +21343,208 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
ExecDropSingleTupleTableSlot(srcslot);
- FreeExecutorState(estate);
-
- foreach(listptr, partContexts)
- deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
-
/* Need to close table and free buffers for DEFAULT partition. */
if (isOldDefaultPart)
{
Relation defaultPartRel = defaultPartCtx->partRel;
- deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ deleteSplitPartitionContext(defaultPartCtx);
/* Keep the lock until commit. */
table_close(defaultPartRel, NoLock);
}
}
/*
- * createPartitionTable: create table for new partition with given name
- * (newPartName) like table (modelRelName)
+ * findNewPartForSlot: find partition that contains slot value.
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
- * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * si: SPLIT PARTITION context.
+ * checkPc: partition context for check slot value (can be NULL).
+ * slot: value to check.
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
- AlterTableUtilityContext *context)
+static SplitPartitionContext *
+findNewPartForSlot(SplitInfo * si, SplitPartitionContext * checkPc, TupleTableSlot *slot)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
+ ListCell *listptr;
+ ExprContext *econtext;
+ MemoryContext oldCxt;
+ SplitPartitionContext *result = NULL;
- 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;
+ econtext = GetPerTupleExprContext(si->estate);
- tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ /* Make sure the tuple is fully deconstructed. */
+ slot_getallattrs(slot);
+
+ econtext->ecxt_scantuple = slot;
/*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * Switch to per-tuple memory context and reset it after each check, so we
+ * don't leak memory.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY);
- tlc->relationOid = InvalidOid;
- createStmt->tableElts = lappend(createStmt->tableElts, tlc);
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(si->estate));
- /* 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;
+ if (checkPc)
+ {
+ if (ExecCheck(checkPc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = checkPc;
+ }
+ }
+ else
+ {
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, si->partContexts)
+ {
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
- ProcessUtility(wrapper,
- context->queryString,
- false,
- PROCESS_UTILITY_SUBCOMMAND,
- NULL,
- NULL,
- None_Receiver,
- NULL);
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ ResetExprContext(econtext);
+ result = pc;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+
+ /* We not found partition with borders but exists DEFAULT partition. */
+ if (!result && si->defaultPartCtx)
+ result = si->defaultPartCtx;
+
+ /*
+ * "result" can be NULL here because can be spaces between of the new
+ * partitions and rows from the spaces can be moved to the DEFAULT
+ * partition of the partitioned table.
+ */
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ return result;
+}
+
+/*
+ * findNewPartWithAllRows: find partition that contains all the rows of the
+ * split partition; returns partition context if partition was found.
+ *
+ * si: SPLIT PARTITION context.
+ */
+static SplitPartitionContext *
+findNewPartWithAllRows(SplitInfo * si)
+{
+ PartitionKey key = RelationGetPartitionKey(si->rel);
+ ListCell *index;
+ int partnatts;
+ SplitPartitionContext *result = NULL;
+ AttrMap *map;
+ AttrNumber *partattrs;
+ int i;
+
+ /* We can use optimization for BY RANGE partitioning only. */
+ if (key->strategy != PARTITION_STRATEGY_RANGE)
+ return NULL;
+
+ partnatts = get_partition_natts(key);
+
+ /*
+ * Partition key contains columns of partitioned tables si->rel but index
+ * contains columns of si->splitRel. So we need a map for convert
+ * attributes numbers (si->rel) -> (si->splitRel).
+ */
+ map = build_attrmap_by_name_if_req(RelationGetDescr(si->splitRel),
+ RelationGetDescr(si->rel),
+ false);
+ if (map)
+ {
+ /*
+ * Columns order in a partitioned table and split partition is
+ * different. So need to create a new array with attribute numbers.
+ */
+ partattrs = palloc(sizeof(AttrNumber) * partnatts);
+ for (i = 0; i < partnatts; i++)
+ {
+ AttrNumber attr_num = get_partition_col_attnum(key, i);
+
+ partattrs[i] = map->attnums[attr_num - 1];
+ }
+ }
+ else
+ {
+ /* We can use array of partition key. */
+ partattrs = key->partattrs;
+ }
+
+ /* Scan all indexes of split partition. */
+ foreach(index, RelationGetIndexList(si->splitRel))
+ {
+ Oid thisIndexOid = lfirst_oid(index);
+ Relation indexRel = index_open(thisIndexOid, AccessShareLock);
+
+ /*
+ * Index should be valid, btree (for searching min/max) and contain
+ * the same columns as partition key.
+ */
+ if (indexRel->rd_index->indisvalid &&
+ indexRel->rd_rel->relam == BTREE_AM_OID &&
+ indexRel->rd_index->indnatts == partnatts)
+ {
+ for (i = 0; i < indexRel->rd_index->indnatts; i++)
+ {
+ if (indexRel->rd_index->indkey.values[i] != partattrs[i])
+ break;
+ }
+
+ /* Index found? */
+ if (i == indexRel->rd_index->indnatts)
+ {
+ IndexScanDesc indexScan;
+ TupleTableSlot *slot;
+
+ indexScan = index_beginscan(si->splitRel, indexRel, SnapshotAny, 0, 0);
+ do
+ {
+ SplitPartitionContext *pc;
+
+ /* Search a minimum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, ForwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Find partition context for minimum index value. */
+ pc = findNewPartForSlot(si, NULL, slot);
+ ExecDropSingleTupleTableSlot(slot);
+
+ /* Search a maximum index value. */
+ index_rescan(indexScan, NULL, 0, NULL, 0);
+ slot = table_slot_create(si->splitRel, NULL);
+ if (!index_getnext_slot(indexScan, BackwardScanDirection, slot))
+ {
+ ExecDropSingleTupleTableSlot(slot);
+ break;
+ }
+ /* Check partition context "pc" for maximum index value. */
+ result = findNewPartForSlot(si, pc, slot);
+ ExecDropSingleTupleTableSlot(slot);
+ } while (0);
+
+ index_endscan(indexScan);
+ index_close(indexRel, AccessShareLock);
+ goto done;
+ }
+ }
+ index_close(indexRel, AccessShareLock);
+ }
+
+done:
+ if (map)
+ {
+ pfree(partattrs);
+ free_attrmap(map);
+ }
+ return result;
}
/*
@@ -21178,16 +21556,14 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
- Oid namespaceId;
- ListCell *listptr,
- *listptr2;
+ ListCell *listptr;
bool isSameName = false;
char tmpRelName[NAMEDATALEN];
- List *newPartRels = NIL;
ObjectAddress object;
RangeVar *splitPartName = cmd->name;
Oid defaultPartOid;
+ SplitPartitionContext *pcWithAllRows;
+ SplitInfo *si;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -21206,35 +21582,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
- foreach(listptr, cmd->partlist)
- {
- Oid existing_relid;
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
-
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
- /*
- * Look up the namespace in which we are supposed to create the
- * partition, check we have permission to create there, lock it
- * against concurrent drop, and mark stmt->relation as
- * RELPERSISTENCE_TEMP if a temporary namespace is selected.
- */
- namespaceId =
- RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
-
- /*
- * This would fail later on anyway, if the relation already exists.
- * But by catching it here we can emit a nicer error message.
- */
- existing_relid = get_relname_relid(relname, namespaceId);
- if (existing_relid == splitRelOid && !isSameName)
- /* One new partition can have the same name as split partition. */
- isSameName = true;
- else if (existing_relid != InvalidOid)
- ereport(ERROR,
- (errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname)));
- }
+ isSameName = checkNewPartitions(cmd, splitRelOid);
/* Detach split partition. */
RemoveInheritance(splitRel, rel, false);
@@ -21265,43 +21613,48 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
CommandCounterIncrement();
}
- /* Create new partitions (like split partition), without indexes. */
- foreach(listptr, cmd->partlist)
- {
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel;
+ /* Create SPLIT PARTITION context. */
+ si = createSplitInfo(cmd, rel, splitRel, defaultPartOid);
- createPartitionTable(sps->name, splitPartName, context);
+ /*
+ * Optimization: if exist a new partition that contains all the rows of
+ * the split partition then do not copy rows, rename the split partition.
+ */
+ pcWithAllRows = findNewPartWithAllRows(si);
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+ /* Create new partitions (like split partition), without indexes. */
+ splitPartName = createNewPartitions(si, splitPartName, pcWithAllRows, context);
- newPartRels = lappend(newPartRels, newPartRel);
+ if (!pcWithAllRows)
+ {
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(si);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
}
- /* Copy data from split partition to new partitions. */
- moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
- /* Keep the lock until commit. */
- table_close(splitRel, NoLock);
-
/* Attach new partitions to partitioned table. */
- forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ foreach(listptr, si->partContexts)
{
- SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
- Relation newPartRel = (Relation) lfirst(listptr2);
+ SplitPartitionContext *pc = (SplitPartitionContext *) lfirst(listptr);
/* wqueue = NULL: verification for each cloned constraint is not need. */
- attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ attachPartitionTable(NULL, rel, pc->partRel, pc->sps->bound);
/* Keep the lock until commit. */
- table_close(newPartRel, NoLock);
+ table_close(pc->partRel, NoLock);
}
- /* Drop split partition. */
- object.classId = RelationRelationId;
- object.objectId = splitRelOid;
- object.objectSubId = 0;
- /* Probably DROP_CASCADE is not needed. */
- performDeletion(&object, DROP_RESTRICT, 0);
+ if (!pcWithAllRows)
+ {
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ deleteSplitInfo(si);
}
/*
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 7eb52f6feef..a8f3d8d6d17 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,311 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 0 rows:
+SELECT i FROM test_def;
+ i
+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 17
+ 11
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a17 | 17
+ a11 | 11
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+ i
+----
+ 15
+ 12
+ 11
+(3 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a15 | 15
+ a12 | 12
+ a11 | 11
+ a27 | 27
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 0 rows:
+SELECT i FROM test_2;
+ i
+---
+(0 rows)
+
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+ i
+----
+ 25
+ 22
+ 27
+ 21
+(4 rows)
+
+-- should be 6 rows:
+SELECT * FROM test;
+ name | i
+------+----
+ a1 | 1
+ a5 | 5
+ a25 | 25
+ a22 | 22
+ a27 | 27
+ a21 | 21
+(6 rows)
+
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ t
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+ b | s
+---+---
+(0 rows)
+
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+ b | s
+------------+---
+ 1000000010 | 3
+ 1000000003 | 5
+ 1000000120 | 4
+ 1000000124 | 2
+(4 rows)
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+ ?column?
+----------
+ f
+(1 row)
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+ b | s
+------------+---
+ 1000000120 | 4
+ 1000000124 | 2
+(2 rows)
+
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+ b | s
+------------+---
+ 1000000200 | 1
+(1 row)
+
+DROP TABLE test_2colkey CASCADE;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 40c71889b6e..17341353e09 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,157 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+--
+-- Tests for SPLIT optimization (BY RANGE partitioning): if one of the new
+-- partitions contains all the rows of the split partition, then we can rename
+-- the split partition instead of creating a new partition and moving the rows.
+--
+-- 1. Optimization should be used.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_2" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 0 rows:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 2. Optimization cannot be used because not exists btree-index on the
+-- partition key (it is used to check the placement of rows in the partitions).
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a17', 17), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 17, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 3. Optimization cannot be used because rows should be moved into different
+-- partitions.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a15', 15), ('a12', 12), ('a27', 27), ('a11', 11);
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 'f' (tables "test_2" and "test_def" should be different):
+SELECT 'test_2'::regclass::oid=:prev_oid;
+-- should be rows 15, 12, 11:
+SELECT i FROM test_2;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 4. Optimization should be used, DEFAUT partition renames to DEFAULT
+-- partition.
+--
+CREATE TABLE test(name text, i int) PARTITION BY RANGE (i);
+CREATE TABLE test_1 PARTITION OF test FOR VALUES FROM (1) TO (10);
+CREATE TABLE test_def PARTITION OF test DEFAULT;
+CREATE INDEX idx_test_i ON test(i);
+INSERT INTO test(name, i) VALUES
+ ('a1', 1), ('a5', 5), ('a25', 25), ('a22', 22), ('a27', 27), ('a21', 21);
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+SELECT 'test_def'::regclass::oid AS prev_oid \gset
+ALTER TABLE test SPLIT PARTITION test_def INTO
+ (PARTITION test_def DEFAULT, PARTITION test_2 FOR VALUES FROM (11) TO (19));
+-- should be 't' (table "test_def" after SPLIT should be the same as table
+-- "test_def" before SPLIT):
+SELECT 'test_def'::regclass::oid=:prev_oid;
+-- should be 0 rows:
+SELECT i FROM test_2;
+-- should be rows 25, 22, 27, 21:
+SELECT i FROM test_def;
+-- should be 6 rows:
+SELECT * FROM test;
+DROP TABLE test CASCADE;
+--
+-- 5. Optimization should be used, 2-column partition key + different columns
+-- order in partitions.
+--
+CREATE TABLE test_2colkey(s smallint, b bigint, t text) PARTITION BY RANGE (b, s);
+CREATE TABLE test_2colkey_1 PARTITION OF test_2colkey FOR VALUES FROM (1000000001, 1) TO (1000000100, 100);
+CREATE TABLE test_2colkey_def(i int, b bigint, s smallint, t text);
+ALTER TABLE test_2colkey_def DROP COLUMN i;
+ALTER TABLE test_2colkey ATTACH PARTITION test_2colkey_def DEFAULT;
+CREATE INDEX idx_test_2colkey_s_b ON test_2colkey(b, s);
+
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000010, 3, 'value_10_3');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000120, 4, 'value_120_4');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000003, 5, 'value_3_5');
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000124, 2, 'value_124_2');
+
+-- should be 4 rows:
+SELECT b, s FROM test_2colkey;
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_def;
+
+SELECT 'test_2colkey_def'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_def INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000200, 100),
+ PARTITION test_2colkey_def DEFAULT);
+
+-- should be 't' (table "test_2colkey_2" after SPLIT should be the same as table
+-- "test_2colkey_def" before SPLIT):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 0 rows:
+SELECT b, s FROM test_2colkey_def;
+-- should be 6 rows:
+SELECT b, s FROM test_2colkey;
+
+--
+-- 5.1. Optimization cannot be used.
+--
+INSERT INTO test_2colkey (b, s, t) VALUES (1000000200, 1, 'value_200_1');
+
+SELECT 'test_2colkey_2'::regclass::oid AS prev_oid \gset
+
+ALTER TABLE test_2colkey SPLIT PARTITION test_2colkey_2 INTO
+ (PARTITION test_2colkey_2 FOR VALUES FROM (1000000101, 1) TO (1000000150, 100),
+ PARTITION test_2colkey_3 FOR VALUES FROM (1000000151, 1) TO (1000000200, 100));
+
+-- should be 'f' (optimization is not used):
+SELECT 'test_2colkey_2'::regclass::oid=:prev_oid;
+
+-- should be 2 rows:
+SELECT b, s FROM test_2colkey_2;
+-- should be 1 row:
+SELECT b, s FROM test_2colkey_3;
+
+DROP TABLE test_2colkey CASCADE;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
0002-ALTER-TABLE-SPLIT-PARTITION-command-v26.patchapplication/octet-stream; name=0002-ALTER-TABLE-SPLIT-PARTITION-command-v26.patchDownload
From 98c2c8dce4a02bffaa4c0e7d9afdba9e0186b985 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH 2/4] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 406 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 3679 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2f9889b419f..ef944e3733b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4736,6 +4739,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5159,6 +5166,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5561,6 +5573,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6559,6 +6579,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20844,6 +20866,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20898,6 +21169,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *splitPartName = cmd->name;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(splitPartName, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+ splitPartName = makeRangeVar(get_namespace_name(RelationGetNamespace(splitRel)),
+ tmpRelName, -1);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, splitPartName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0d9d351b445..16d766786b5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2300,6 +2303,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2344,6 +2364,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17595,6 +17629,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18226,6 +18261,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca42..88a4a41186a 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721ed..c36e26ba4bd 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a51717e36ce..65d64241563 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13029,3 +13029,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 27c28139c84..03c1f27053f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2344,6 +2344,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index e2b4700d97b..480896e7b66 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -415,6 +415,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd848..9d2a26705f0 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02c..6d860806221 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..5d9e8b0925f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a6254..0342eb39e40 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..087239a4a19
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b21..265ef2a5470 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..7eb52f6feef
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 026e7a77675..7cd4deda9bf 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..40c71889b6e
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index aa3025676fd..877c1101f2e 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2666,6 +2666,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.3 (Apple Git-145)
0001-ALTER-TABLE-MERGE-PARTITIONS-command-v26.patchapplication/octet-stream; name=0001-ALTER-TABLE-MERGE-PARTITIONS-command-v26.patchDownload
From 2f1b8f766129a5e563df5aac86510add2052e71c Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH 1/4] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 349 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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, 2099 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 8a02c5b05b6..2f9889b419f 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4734,6 +4736,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5153,6 +5159,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);
@@ -5550,6 +5561,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);
@@ -6540,6 +6559,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:
@@ -19034,6 +19055,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19236,23 +19288,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20806,3 +20843,281 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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 a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, 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. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning queries
+ * involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /* 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 c1b0cff1c9e..0d9d351b445 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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
PERIOD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2310,6 +2310,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2324,6 +2325,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2337,6 +2339,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2353,6 +2370,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17510,6 +17528,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
@@ -18128,6 +18147,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8cee..48a23c7ca42 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3f..9ed80d721ed 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 b89baef95d3..27c28139c84 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -933,6 +933,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -941,6 +952,8 @@ 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;
@@ -2331,6 +2344,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 57514d064b7..e2b4700d97b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f7..0329d7bd848 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 00000000000..98446aaab5a
--- /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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85e..8bcaa8a6254 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 00000000000..ec48732c583
--- /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 48563b2cf01..69920757b21 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 00000000000..013ab659618
--- /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 5ac6e871f54..026e7a77675 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..8bf90fd6212
--- /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 cfa9d5aaeac..aa3025676fd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2602,6 +2602,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.39.3 (Apple Git-145)
Hi!
I've fixed that by skipping a copy of the identity of another
partition (remove CREATE_TABLE_LIKE_IDENTITY from
TableLikeClause.options).
Thanks for correction!
Probably I should have looked at the code more closely after commit [1]https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49.
I'm also very glad that situation [2]/messages/by-id/171085360143.2046436.7217841141682511557.pgcf@coridan.postgresql.org was reproduced.
When merging partitions you're creating a merged partition like the
parent table. But when splitting a partition you're creating new
partitions like the partition being split. What motivates this
difference?
When splitting a partition, I planned to set parameters for each of the
new partitions (for example, tablespace parameter).
It would make sense if we want to transfer part of the data of splitting
partition to a slower (archive) storage device.
Right now I haven't seen any interest in this functionality, so it
hasn't been implemented yet. But I think this will be needed in the future.
Special thanks for the hint that new structures should be added to the
list src\tools\pgindent\typedefs.list.
Links.
[1]: https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49
https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49
[2]: /messages/by-id/171085360143.2046436.7217841141682511557.pgcf@coridan.postgresql.org
/messages/by-id/171085360143.2046436.7217841141682511557.pgcf@coridan.postgresql.org
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi, Dmitry!
Thank you for your feedback!
On Wed, Mar 27, 2024 at 10:18 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
I've fixed that by skipping a copy of the identity of another
partition (remove CREATE_TABLE_LIKE_IDENTITY from
TableLikeClause.options).Thanks for correction!
Probably I should have looked at the code more closely after commit [1].
I'm also very glad that situation [2] was reproduced.When merging partitions you're creating a merged partition like the
parent table. But when splitting a partition you're creating new
partitions like the partition being split. What motivates this
difference?When splitting a partition, I planned to set parameters for each of the
new partitions (for example, tablespace parameter).
It would make sense if we want to transfer part of the data of splitting
partition to a slower (archive) storage device.
Right now I haven't seen any interest in this functionality, so it
hasn't been implemented yet. But I think this will be needed in the future.
OK, I've changed the code to use the parent table as a template for
new partitions in split case. So, now it's the same in both split and
merge cases.
I also added a special note into docs about ACCESS EXCLUSIVE lock,
because I believe that's a significant limitation for usage of this
functionality.
I think 0001, 0002 and 0003 could be considered for pg17. I will
continue reviewing them.
0004 might require more work. I didn't rebase it for now. I suggest
we can rebase it later and consider for pg18.
------
Regards,
Alexander Korotkov
Attachments:
0001-ALTER-TABLE-MERGE-PARTITIONS-command-v27.patchapplication/octet-stream; name=0001-ALTER-TABLE-MERGE-PARTITIONS-command-v27.patchDownload
From 87f94368ca564486a51b0172a3eb0f5f49180387 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH 1/3] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 349 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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, 2099 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 6741e721ae3..3541ebebd65 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4738,6 +4740,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5157,6 +5163,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);
@@ -5554,6 +5565,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);
@@ -6544,6 +6563,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:
@@ -19038,6 +19059,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19240,23 +19292,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20810,3 +20847,281 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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 a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, 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. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning queries
+ * involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /* 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 c1b0cff1c9e..0d9d351b445 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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
PERIOD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2310,6 +2310,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2324,6 +2325,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2337,6 +2339,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2353,6 +2370,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17510,6 +17528,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
@@ -18128,6 +18147,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8cee..48a23c7ca42 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3f..9ed80d721ed 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 b89baef95d3..27c28139c84 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -933,6 +933,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -941,6 +952,8 @@ 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;
@@ -2331,6 +2344,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 57514d064b7..e2b4700d97b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f7..0329d7bd848 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 00000000000..98446aaab5a
--- /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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85e..8bcaa8a6254 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 00000000000..ec48732c583
--- /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 48563b2cf01..69920757b21 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 00000000000..013ab659618
--- /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 5ac6e871f54..026e7a77675 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..8bf90fd6212
--- /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 cfa9d5aaeac..aa3025676fd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2602,6 +2602,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.39.3 (Apple Git-145)
0002-ALTER-TABLE-SPLIT-PARTITION-command-v27.patchapplication/octet-stream; name=0002-ALTER-TABLE-SPLIT-PARTITION-command-v27.patchDownload
From 8e5ffacede40a549071a3ae177465c0ac4d607e6 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 406 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 3679 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3541ebebd65..506db7f5a1d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4740,6 +4743,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5163,6 +5170,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5565,6 +5577,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6563,6 +6583,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20848,6 +20870,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20902,6 +21173,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *parentName;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1);
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, parentName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0d9d351b445..16d766786b5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2300,6 +2303,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2344,6 +2364,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17595,6 +17629,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18226,6 +18261,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca42..88a4a41186a 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721ed..c36e26ba4bd 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a51717e36ce..65d64241563 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13029,3 +13029,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 27c28139c84..03c1f27053f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2344,6 +2344,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index e2b4700d97b..480896e7b66 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -415,6 +415,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd848..9d2a26705f0 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02c..6d860806221 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..5d9e8b0925f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a6254..0342eb39e40 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..087239a4a19
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b21..265ef2a5470 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..7eb52f6feef
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 026e7a77675..7cd4deda9bf 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..40c71889b6e
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index aa3025676fd..877c1101f2e 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2666,6 +2666,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.3 (Apple Git-145)
0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME-v27.patchapplication/octet-stream; name=0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME-v27.patchDownload
From 631a522e56fc8e586bb490601ae292739bcaa864 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 138 +++++++++++++++++++++++++++++-
1 file changed, 135 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef8..945228d84b1 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1125,113 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1474,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1891,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.39.3 (Apple Git-145)
Hi, Alexander!
Thank you very much for your work on refactoring the commits!
Yesterday I received an email from adjkldd@126.com <winterloo@126.com>
with a proposal for optimization (MERGE PARTITION command) for cases
where the target partition has a name identical to one of the merging
partition names.
I think this optimization is worth considering.
A simplified version of the optimization is attached to this letter
(difference is 10-15 lines).
All changes made in one commit
(v28-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patch) and in one
function (ATExecMergePartitions).
In your opinion, should we added this optimization now or should it be
left for later?
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v28-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v28-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From 873ddc54de176590efdd61121355f850359cfd1a Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v28 1/3] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 348 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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, 2098 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 6741e721ae..61ed046102 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4738,6 +4740,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5157,6 +5163,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);
@@ -5554,6 +5565,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);
@@ -6544,6 +6563,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:
@@ -19038,6 +19059,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19240,23 +19292,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20810,3 +20847,280 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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;
+ newPartRel = mergingPartition;
+ }
+ else
+ {
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ if (isSameName)
+ {
+ /* Detach partition that we re-use for merged partition. */
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(newPartRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, newPartRel, false, defaultPartOid);
+
+ /* Make these updates visible */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ /* Create table for new partition, use partitioned table as model. */
+ createPartitionTable(mergePartName,
+ makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1),
+ context);
+
+ /*
+ * Open the new partition and acquire exclusive lock on it. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning
+ * queries involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ }
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c1b0cff1c9..0d9d351b44 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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
PERIOD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2310,6 +2310,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2324,6 +2325,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2337,6 +2339,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2353,6 +2370,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17510,6 +17528,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
@@ -18128,6 +18147,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8ce..48a23c7ca4 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3..9ed80d721e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 b89baef95d..27c28139c8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -933,6 +933,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -941,6 +952,8 @@ 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;
@@ -2331,6 +2344,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 57514d064b..e2b4700d97 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85..8bcaa8a625 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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..b53df2703b
--- /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
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 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
+(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 5ac6e871f5..026e7a7767 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 cfa9d5aaea..aa3025676f 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2602,6 +2602,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v28-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v28-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From 86a6f2b37e28fdcf4eff64701b1fdf77a51f3c52 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v28 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 406 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 3679 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 61ed046102..e9ebb59d76 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4740,6 +4743,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5163,6 +5170,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5565,6 +5577,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6563,6 +6583,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20848,6 +20870,255 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid, ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20902,6 +21173,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *parentName;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1);
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, parentName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0d9d351b44..16d766786b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2300,6 +2303,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2344,6 +2364,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17595,6 +17629,7 @@ unreserved_keyword:
| SIMPLE
| SKIP
| SNAPSHOT
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18226,6 +18261,7 @@ bare_label_keyword:
| SMALLINT
| SNAPSHOT
| SOME
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca4..88a4a41186 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721e..c36e26ba4b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a51717e36c..65d6424156 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13029,3 +13029,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 27c28139c8..03c1f27053 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2344,6 +2344,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index e2b4700d97..480896e7b6 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -415,6 +415,7 @@ PG_KEYWORD("skip", SKIP, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a625..0342eb39e4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7eb52f6fee
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 026e7a7767..7cd4deda9b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..40c71889b6
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index aa3025676f..877c1101f2 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2666,6 +2666,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v28-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v28-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 1b31a961b0aff84aa80f85a0ef00498ea1176ac6 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v28 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 138 +++++++++++++++++++++++++++++-
1 file changed, 135 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef..945228d84b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1125,113 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1474,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1891,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
Hi!
Patch stop applying due to changes in upstream.
Here is a rebased version.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v29-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchtext/plain; charset=UTF-8; name=v29-0001-ALTER-TABLE-MERGE-PARTITIONS-command.patchDownload
From c385b3e8c1aa96036d30ab1bfdbe22b1bde01524 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 16:06:03 +0300
Subject: [PATCH v29 1/3] ALTER TABLE MERGE PARTITIONS command
---
src/backend/commands/tablecmds.c | 353 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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, 2103 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 a28f405e27..9914fc0d9a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4746,6 +4748,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5165,6 +5171,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);
@@ -5562,6 +5573,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);
@@ -6556,6 +6575,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:
@@ -19051,6 +19072,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19253,23 +19305,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20823,3 +20860,285 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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. */
+ {
+ bool insertIndexes;
+
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate, &insertIndexes);
+ }
+
+ 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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;
+ newPartRel = mergingPartition;
+ }
+ else
+ {
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ if (isSameName)
+ {
+ /* Detach partition that we re-use for merged partition. */
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(newPartRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, newPartRel, false, defaultPartOid);
+
+ /* Make these updates visible */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ /* Create table for new partition, use partitioned table as model. */
+ createPartitionTable(mergePartName,
+ makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1),
+ context);
+
+ /*
+ * Open the new partition and acquire exclusive lock on it. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning
+ * queries involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ }
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 682748eb4b..d7ef1d95b9 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -757,7 +757,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
PERIOD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2312,6 +2312,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2326,6 +2327,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2339,6 +2341,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2355,6 +2372,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17528,6 +17546,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
@@ -18148,6 +18167,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8ce..48a23c7ca4 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3..9ed80d721e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 a690ebc6e5..abb705d11d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -934,6 +934,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -942,6 +953,8 @@ 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;
@@ -2332,6 +2345,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 6c959e85d5..2304165408 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85..8bcaa8a625 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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..b53df2703b
--- /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
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 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
+(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 5ac6e871f5..026e7a7767 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
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 a8d7bed411..a899944dcd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2603,6 +2603,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v29-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchtext/plain; charset=UTF-8; name=v29-0002-ALTER-TABLE-SPLIT-PARTITION-command.patchDownload
From c380128fb90dc2afc8238294e5bc4c02dc325df8 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 19 Sep 2022 17:58:52 +0300
Subject: [PATCH v29 2/3] ALTER TABLE SPLIT PARTITION command
---
src/backend/commands/tablecmds.c | 411 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 3684 insertions(+), 12 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9914fc0d9a..acf49b2057 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4748,6 +4751,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5171,6 +5178,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5573,6 +5585,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6575,6 +6595,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20861,6 +20883,260 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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. */
+ {
+ bool insertIndexes;
+
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate, &insertIndexes);
+ }
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20915,6 +21191,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *parentName;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1);
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, parentName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d7ef1d95b9..11c958305a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -647,6 +648,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -772,7 +775,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SPLIT SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2302,6 +2305,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2346,6 +2366,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17614,6 +17648,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18247,6 +18282,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca4..88a4a41186 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721e..c36e26ba4b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0f7f40c50f..150ff7abd5 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13066,3 +13066,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index abb705d11d..8602f791ca 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2345,6 +2345,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 2304165408..6f19f166a6 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -416,6 +416,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a625..0342eb39e4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7eb52f6fee
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ...ALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...est FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+ERROR: new partitions not have value 'Volgograd' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+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
+ 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
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-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_west;
+ 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
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Magadan | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 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
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central 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;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 026e7a7767..7cd4deda9b 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..40c71889b6
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok', 'Murmansk'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Voronezh', 'Volgograd'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', NULL),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+-- ERROR: new partitions not have value 'Volgograd' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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_all PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Kazan', 'Khabarovsk', 'Volgograd', 'Vladivostok');
+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');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central 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;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a899944dcd..1c9265d575 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2667,6 +2667,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v29-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchtext/plain; charset=UTF-8; name=v29-0003-Documentation-for-ALTER-TABLE-SPLIT-PARTITION-ME.patchDownload
From 0164d86e4d62cb35f514c1c32ff1659aedfa42c3 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Tue, 28 Mar 2023 10:50:19 +0300
Subject: [PATCH v29 3/3] Documentation for ALTER TABLE SPLIT PARTITION/MERGE
PARTITIONS commands
---
doc/src/sgml/ref/alter_table.sgml | 138 +++++++++++++++++++++++++++++-
1 file changed, 135 insertions(+), 3 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef..945228d84b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,13 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1125,113 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merge several partitions into one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1474,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1891,31 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'),
+ PARTITION sales_east FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'));
+</programlisting></para>
+
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
--
2.40.1.windows.1
Hi!
On Sun, Mar 31, 2024 at 5:12 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Patch stop applying due to changes in upstream.
Here is a rebased version.
I've revised the patchset. Now there are two self-contained patches
coming with the documentation. Also, now each command has a paragraph
in the "Data definition" chapter. Also documentation and tests
contain geographical partitioning with all Russian cities. I think
that might create a country-centric feeling for the reader. I've
edited that to make cities spread around the world to reflect the
international spirit. Hope you're OK with this. Now, both merge and
split commands make new partitions using the parent table as the
template. And some other edits to comments, commit messages,
documentation etc.
I think this patch is well-reviewed and also has quite straightforward
implementation. The major limitation of holding ACCESS EXCLUSIVE LOCK
on the parent table is well-documented. I'm going to push this if no
objections.
------
Regards,
Alexander Korotkov
Attachments:
v30-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v30-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 8b6ac3cf33f4999bb1352e7de8a10e59292f0f08 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 2 Apr 2024 23:27:29 +0300
Subject: [PATCH v30 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 65 +-
src/backend/commands/tablecmds.c | 411 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
19 files changed, 3766 insertions(+), 14 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index f9f2778b3d7..8ff9a520ca9 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4400,6 +4400,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e0a98bc5385..a1703155854 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1121,6 +1125,44 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1188,7 +1230,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1432,7 +1475,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1848,6 +1891,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 05e86de8ebc..582890a3025 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4740,6 +4743,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5163,6 +5170,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5565,6 +5577,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6567,6 +6587,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20852,6 +20874,260 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ bool insert_indexes;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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. We ignore the
+ * 'insert_indexes' flag since newPartRel has no indexes anyway.
+ */
+ (void) table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate, &insert_indexes);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20906,6 +21182,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *parentName;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1);
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, parentName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f2b0d963d18..e6c12f5287e 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -270,6 +270,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -647,6 +648,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -772,7 +775,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2302,6 +2305,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2346,6 +2366,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17615,6 +17649,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18248,6 +18283,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca42..88a4a41186a 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721ed..c36e26ba4bd 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0f7f40c50f6..150ff7abd5f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13066,3 +13066,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index abb705d11d7..8602f791ca9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2345,6 +2345,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 23041654082..6f19f166a66 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -416,6 +416,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd848..9d2a26705f0 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02c..6d860806221 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..5d9e8b0925f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a6254..0342eb39e40 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..087239a4a19
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b21..265ef2a5470 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..0a40f20554d
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Kyiv' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions not have value 'Kyiv' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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 | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 026e7a77675..7cd4deda9bf 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..8864f6ddaa1
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions not have value 'Kyiv' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index f383dd417ee..34ef3ee4e5a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2675,6 +2675,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.3 (Apple Git-145)
v30-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v30-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From ec83a934dcafbcb9c414eb656b87c2840bd64afc Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 2 Apr 2024 23:24:32 +0300
Subject: [PATCH v30 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 354 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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 | 732 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 430 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 2189 insertions(+), 22 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 6bc43ad10ca..f9f2778b3d7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4379,6 +4379,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ administrators to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef8..e0a98bc5385 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1121,74 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1431,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1848,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 317b89f67c3..05e86de8ebc 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4738,6 +4740,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5157,6 +5163,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);
@@ -5554,6 +5565,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);
@@ -6548,6 +6567,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:
@@ -19042,6 +19063,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19244,23 +19296,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20814,3 +20851,286 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+ bool insert_indexes;
+
+ /* 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. We ignore the
+ * 'insert_indexes' flag since newPartRel has no indexes anyway.
+ */
+ (void) table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate, &insert_indexes);
+
+ 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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 a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, 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. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning queries
+ * involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /* 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 f1af6147c37..f2b0d963d18 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -757,7 +757,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
PERIOD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2312,6 +2312,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2326,6 +2327,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2339,6 +2341,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2355,6 +2372,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17529,6 +17547,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
@@ -18149,6 +18168,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PERIOD
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8cee..48a23c7ca42 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3f..9ed80d721ed 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 a690ebc6e51..abb705d11d7 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -934,6 +934,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -942,6 +953,8 @@ 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;
@@ -2332,6 +2345,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 6c959e85d54..23041654082 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -333,6 +333,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("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f7..0329d7bd848 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 00000000000..98446aaab5a
--- /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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85e..8bcaa8a6254 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 00000000000..ec48732c583
--- /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 48563b2cf01..69920757b21 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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 00000000000..2ba0ec47d97
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,732 @@
+--
+-- 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_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)
+
+RESET enable_seqscan;
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 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 | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for test indexes after merge partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5ac6e871f54..026e7a77675 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..bb461e6623a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,430 @@
+--
+-- 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_seqscan = OFF;
+
+SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+DROP SCHEMA partitions_merge_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 8d08386d65c..f383dd417ee 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2611,6 +2611,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.39.3 (Apple Git-145)
Hi!
I've revised the patchset.
Thanks for the corrections (especially ddl.sgml).
Could you also look at a small optimization for the MERGE PARTITIONS
command (in a separate file
v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch, I wrote
about it in an email 2024-03-31 00:56:50)?
Files v31-0001-*.patch, v31-0002-*.patch are the same as
v30-0001-*.patch, v30-0002-*.patch (after rebasing because patch stopped
applying due to changes in upstream).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v31-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v31-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 88ba95c1cbdc4983f27985bd440d71970e69688c Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 2 Apr 2024 23:24:32 +0300
Subject: [PATCH v31 1/3] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 354 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 89 +++
src/backend/partitioning/partbounds.c | 207 +++++
src/include/nodes/parsenodes.h | 14 +
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 | 732 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 430 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
17 files changed, 2189 insertions(+), 22 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 6bc43ad10c..f9f2778b3d 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4379,6 +4379,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ administrators to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 6cdcd779ef..e0a98bc538 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1121,74 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the values lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form a list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1431,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1784,6 +1848,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 317b89f67c..05e86de8eb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4738,6 +4740,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5157,6 +5163,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);
@@ -5554,6 +5565,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);
@@ -6548,6 +6567,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:
@@ -19042,6 +19063,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;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19244,23 +19296,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20814,3 +20851,286 @@ 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 <newPartName> (LIKE <modelRelName>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ */
+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 | CREATE_TABLE_LIKE_IDENTITY);
+ 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);
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+ bool insert_indexes;
+
+ /* 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. We ignore the
+ * 'insert_indexes' flag since newPartRel has no indexes anyway.
+ */
+ (void) table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate, &insert_indexes);
+
+ 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = 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);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for prevent DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot merge non-table partition \"%s\"",
+ RelationGetRelationName(mergingPartition))));
+
+ /*
+ * 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 a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, 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. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning queries
+ * involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /*
+ * Attach a new partition to the 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, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /* 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 6ea68722e3..1fcdb25142 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -761,7 +761,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
@@ -2317,6 +2317,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2331,6 +2332,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2344,6 +2346,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2360,6 +2377,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17668,6 +17686,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18292,6 +18311,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index c7efd8d8ce..48a23c7ca4 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"
@@ -3413,6 +3415,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
@@ -3683,6 +3759,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 c28639d2e3..9ed80d721e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,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 76d91e547b..6e8a2b59e8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -937,6 +937,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -945,6 +956,8 @@ 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;
@@ -2398,6 +2411,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 2d4a0c6a07..a4834eb9b7 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 188fc04f85..8bcaa8a625 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -103,6 +103,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 48563b2cf0..69920757b2 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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..2ba0ec47d9
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,732 @@
+--
+-- 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_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)
+
+RESET enable_seqscan;
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 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 | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for test indexes after merge partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index e9184b5a40..0bd1444767 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bb461e6623
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,430 @@
+--
+-- 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_seqscan = OFF;
+
+SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+DROP SCHEMA partitions_merge_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index f3b8641d76..eadb33e617 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2628,6 +2628,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v31-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v31-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 28e5b5e0257092940c52617d8205ef643692e846 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 2 Apr 2024 23:27:29 +0300
Subject: [PATCH v31 2/3] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 65 +-
src/backend/commands/tablecmds.c | 411 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 62 +-
src/backend/partitioning/partbounds.c | 657 ++++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1417 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 833 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
19 files changed, 3766 insertions(+), 14 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index f9f2778b3d..cd8304ef75 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4400,6 +4400,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e0a98bc538..a170315585 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1121,6 +1125,44 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1188,7 +1230,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1432,7 +1475,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1848,6 +1891,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 05e86de8eb..582890a302 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -670,6 +670,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4740,6 +4743,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5163,6 +5170,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5565,6 +5577,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6567,6 +6587,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20852,6 +20874,260 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for insert rows from splited partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for check slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for insert row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relation's.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ bool insert_indexes;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map for copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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. We ignore the
+ * 'insert_indexes' flag since newPartRel has no indexes anyway.
+ */
+ (void) table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate, &insert_indexes);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for new partition with given name
* (newPartName) like table (modelRelName)
@@ -20906,6 +21182,141 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL);
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ RangeVar *parentName;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for prevent DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ if (splitRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot split non-table partition \"%s\"",
+ RelationGetRelationName(splitRel))));
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway, if the relation already exists.
+ * But by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reuse name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after rename.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1);
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ createPartitionTable(sps->name, parentName, context);
+
+ /* Open the new partition and acquire exclusive lock on it. */
+ newPartRel = table_openrv(sps->name, AccessExclusiveLock);
+
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /* wqueue = NULL: verification for each cloned constraint is not need. */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 1fcdb25142..ee7a89045c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -269,6 +269,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -646,6 +647,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2307,6 +2310,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2351,6 +2371,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17756,6 +17790,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18393,6 +18428,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 48a23c7ca4..88a4a41186 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3415,6 +3415,43 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
@@ -3751,7 +3788,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3759,6 +3796,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3767,7 +3805,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contains at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4172,13 +4214,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4187,9 +4229,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4197,7 +4239,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9ed80d721e..c36e26ba4b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5040,10 +5040,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5076,6 +5135,604 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" is inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ bool overlap = false;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
+ overlap = true;
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of of "spec" should be equal (or less than or equal
+ * in case defaultPart=true) to upper bound of split partition.
+ */
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
+ overlap = true;
+ }
+
+ if (overlap)
+ {
+ PartitionRangeDatum *datum;
+
+ datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
+ first ? "lower" : "upper",
+ relname,
+ defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ first ? "lower" : "upper"),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition is inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL-value if it contains
+ * split partition (partOid).
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitionde table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+ /* Make Const for get string representation of not found value. */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions not have value %s but split partition has",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c9e3ac88cb..411841047d 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13241,3 +13241,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6e8a2b59e8..01fa1a6c2e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2411,6 +2411,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4834eb9b7..9e4be53d93 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -419,6 +419,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8bcaa8a625..0342eb39e4 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -104,6 +104,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 69920757b2..265ef2a547 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..0a40f20554
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1417 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contains at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+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
+ 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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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_jan_feb2022;
+ salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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_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
+ Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+(3 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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 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
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+ pg_get_constraintdef | conname | conkey
+-------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+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)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (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 salesmans30_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_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmans1_2;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salesmans2_3;
+ salesman_id | salesman_name
+-------------+---------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salesmans3_4;
+ salesman_id | salesman_name
+-------------+---------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salesmans4_5;
+ salesman_id | salesman_name
+-------------+---------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+---------------+-------------+--------------
+ salesman_id | a |
+ salesman_name | |
+(2 rows)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmans01_10;
+ salesman_id | salesman_name
+-------------+---------------
+ 1 | Poirot
+(1 row)
+
+select * from salesmans10_20;
+ salesman_id | salesman_name
+-------------+---------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salesmans20_30;
+ salesman_id | salesman_name
+-------------+---------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salesmans30_40;
+ salesman_id | salesman_name
+-------------+---------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salesmans CASCADE;
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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
+ 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_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+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)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions not have value 'Kyiv' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions not have value 'Kyiv' but split partition has
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 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 | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesman_id | salesman_name | sales_state | sales_amount | sales_date
+-------------+---------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ 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_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(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_feb2022;
+ 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
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesman_id | salesman_name | sales_amount | sales_date
+-------------+---------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 0bd1444767..675c567617 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..8864f6ddaa
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,833 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+SET search_path = partition_split_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_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
+CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contains at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition then add rows into partitioned table
+--
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- 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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; using a index on partition key; check index after split
+--
+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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for test indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema';
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for split DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmans VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesman_id INT REFERENCES salesmans(salesman_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+--
+CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (19, 'Ivanov');
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_40;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) 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_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salesmans VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salesmans01_10;
+SELECT * FROM salesmans10_20;
+SELECT * FROM salesmans20_30;
+SELECT * FROM salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity-column, columns of new partitions are identity-columns too.
+--
+CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+
+CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity-column:
+CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- Split partition has identity-column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
+ (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salesmans (salesman_name) VALUES ('May');
+INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+
+SELECT * FROM salesmans1_2;
+SELECT * FROM salesmans2_3;
+SELECT * FROM salesmans3_4;
+SELECT * FROM salesmans4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split partition 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 new partition with some deleted columns:
+CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+
+INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salesmans10_40 DROP COLUMN d1;
+ALTER TABLE salesmans10_40 DROP COLUMN d2;
+ALTER TABLE salesmans10_40 DROP COLUMN d3;
+
+ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmans VALUES (30, 'Ford');
+
+ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
+ (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salesmans01_10;
+select * from salesmans10_20;
+select * from salesmans20_30;
+select * from salesmans30_40;
+
+DROP TABLE salesmans CASCADE;
+
+--
+-- Test: split sub-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 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: partition "sales_east" would overlap partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions not has NULL value that split partition has.
+-- * new partitions not has a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesman_id INT,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions not have value NULL but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions not have value 'Kyiv' but split partition has
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesman_id SERIAL,
+ 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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for test indexes after split partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+DROP SCHEMA partition_split_schema;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index eadb33e617..c5951fc322 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2692,6 +2692,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patchtext/plain; charset=UTF-8; name=v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patchDownload
From 233c0c414bc1d952d98b2eef4810f881e6afb24d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Fri, 5 Apr 2024 14:15:29 +0300
Subject: [PATCH v31 3/3] Additional patch for ALTER TABLE ... MERGE PARTITIONS
... command
---
src/backend/commands/tablecmds.c | 67 +++++++++----------
src/test/regress/expected/partition_merge.out | 2 +-
2 files changed, 34 insertions(+), 35 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 582890a302..e79aeef920 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21431,7 +21431,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
- char tmpRelName[NAMEDATALEN];
RangeVar *mergePartName = cmd->name;
bool isSameName = false;
@@ -21461,12 +21460,17 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* function transformPartitionCmdForMerge().
*/
if (equal(name, cmd->name))
+ {
/* One new partition can have the same name as merged partition. */
isSameName = true;
-
- /* Store a next merging partition into the list. */
- mergingPartitionsList = lappend(mergingPartitionsList,
- mergingPartition);
+ newPartRel = mergingPartition;
+ }
+ else
+ {
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
}
/* Detach all merged partitions. */
@@ -21482,26 +21486,34 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, 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);
+ /* Detach partition that we re-use for merged partition. */
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(newPartRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, newPartRel, false, defaultPartOid);
+
+ /* Make these updates visible */
+ CommandCounterIncrement();
}
- createPartitionTable(mergePartName,
- makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1),
- context);
+ else
+ {
+ /* Create table for new partition, use partitioned table as model. */
+ createPartitionTable(mergePartName,
+ makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1),
+ context);
- /*
- * Open the new partition and acquire exclusive lock on it. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ /*
+ * Open the new partition and acquire exclusive lock on it. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning
+ * queries involving merging partitions.
+ */
+ newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ }
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
@@ -21529,19 +21541,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
performDeletion(&object, DROP_RESTRICT, 0);
}
list_free(mergingPartitionsList);
-
- /* 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/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2ba0ec47d9..f8dfbfcf41 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -211,13 +211,13 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022, sales_ot
select * from sales_others;
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
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:
--
2.40.1.windows.1
The following review has been posted through the commitfest application:
make installcheck-world: tested, passed
Implements feature: tested, passed
Spec compliant: tested, passed
Documentation: tested, passed
All three patches applied nivcely.
Code fits standart, comments are relevant.
The new status of this patch is: Ready for Committer
Hi, Dmitry!
On Fri, Apr 5, 2024 at 4:00 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
I've revised the patchset.
Thanks for the corrections (especially ddl.sgml).
Could you also look at a small optimization for the MERGE PARTITIONS
command (in a separate file
v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch, I wrote
about it in an email 2024-03-31 00:56:50)?Files v31-0001-*.patch, v31-0002-*.patch are the same as
v30-0001-*.patch, v30-0002-*.patch (after rebasing because patch stopped
applying due to changes in upstream).
I've pushed 0001 and 0002. I didn't push 0003 for the following reasons.
1) This doesn't keep functionality equivalent to 0001. With 0003, the
merged partition will inherit indexes, constraints, and so on from the
one of merging partitions.
2) This is not necessarily an optimization. Without 0003 indexes on
the merged partition are created after moving the rows in
attachPartitionTable(). With 0003 we merge data into the existing
partition which saves its indexes. That might cause a significant
performance loss because mass inserts into indexes may be much slower
than building indexes from scratch.
I think both aspects need to be carefully considered. Even if we
accept them, this needs to be documented. I think now it's too late
for both of these. So, this should wait for v18.
------
Regards,
Alexander Korotkov
Hi, Alexander!
I didn't push 0003 for the following reasons. ....
Thanks for clarifying. You are right, these are serious reasons.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi Alexander and Dmitry,
07.04.2024 01:22, Alexander Korotkov wrote:
I've pushed 0001 and 0002. I didn't push 0003 for the following reasons.
Please try the following (erroneous) query:
CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
ALTER TABLE t2 SPLIT PARTITION t1pa INTO
(PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
that triggers an assertion failure:
TRAP: failed Assert("datums != NIL"), File: "partbounds.c", Line: 3434, PID: 1841459
or a segfault (in a non-assert build):
Program terminated with signal SIGSEGV, Segmentation fault.
#0 pg_detoast_datum_packed (datum=0x0) at fmgr.c:1866
1866 if (VARATT_IS_COMPRESSED(datum) || VARATT_IS_EXTERNAL(datum))
(gdb) bt
#0 pg_detoast_datum_packed (datum=0x0) at fmgr.c:1866
#1 0x000055f38c5d5e3f in bttextcmp (...) at varlena.c:1834
#2 0x000055f38c6030dd in FunctionCall2Coll (...) at fmgr.c:1161
#3 0x000055f38c417c83 in partition_rbound_cmp (...) at partbounds.c:3525
#4 check_partition_bounds_for_split_range (...) at partbounds.c:5221
#5 check_partitions_for_split (...) at partbounds.c:5688
#6 0x000055f38c256c49 in transformPartitionCmdForSplit (...) at parse_utilcmd.c:3451
#7 transformAlterTableStmt (...) at parse_utilcmd.c:3810
#8 0x000055f38c2bdf9c in ATParseTransformCmd (...) at tablecmds.c:5650
...
Best regards,
Alexander
Hi, Alexander!
On Sun, Apr 7, 2024 at 10:00 PM Alexander Lakhin <exclusion@gmail.com> wrote:
07.04.2024 01:22, Alexander Korotkov wrote:
I've pushed 0001 and 0002. I didn't push 0003 for the following reasons.
Please try the following (erroneous) query:
CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
ALTER TABLE t2 SPLIT PARTITION t1pa INTO
(PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
PARTITION t2b FOR VALUES FROM ('B') TO ('C'));that triggers an assertion failure:
TRAP: failed Assert("datums != NIL"), File: "partbounds.c", Line: 3434, PID: 1841459or a segfault (in a non-assert build):
Program terminated with signal SIGSEGV, Segmentation fault.#0 pg_detoast_datum_packed (datum=0x0) at fmgr.c:1866
1866 if (VARATT_IS_COMPRESSED(datum) || VARATT_IS_EXTERNAL(datum))
(gdb) bt
#0 pg_detoast_datum_packed (datum=0x0) at fmgr.c:1866
#1 0x000055f38c5d5e3f in bttextcmp (...) at varlena.c:1834
#2 0x000055f38c6030dd in FunctionCall2Coll (...) at fmgr.c:1161
#3 0x000055f38c417c83 in partition_rbound_cmp (...) at partbounds.c:3525
#4 check_partition_bounds_for_split_range (...) at partbounds.c:5221
#5 check_partitions_for_split (...) at partbounds.c:5688
#6 0x000055f38c256c49 in transformPartitionCmdForSplit (...) at parse_utilcmd.c:3451
#7 transformAlterTableStmt (...) at parse_utilcmd.c:3810
#8 0x000055f38c2bdf9c in ATParseTransformCmd (...) at tablecmds.c:5650
Thank you for spotting this. This seems like a missing check. I'm
going to get a closer look at this tomorrow.
------
Regards,
Alexander Korotkov
08.04.2024 01:15, Alexander Korotkov wrote:
Thank you for spotting this. This seems like a missing check. I'm
going to get a closer look at this tomorrow.
Thanks!
There is also an anomaly with the MERGE command:
CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
CREATE TABLE t3 (i int, t text);
ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa, t3) INTO t2p;
leads to:
ERROR: partition bound for relation "t3" is null
WARNING: problem in alloc set PortalContext: detected write past chunk end in block 0x55f1ef42f820, chunk 0x55f1ef42ff40
WARNING: problem in alloc set PortalContext: detected write past chunk end in block 0x55f1ef42f820, chunk 0x55f1ef42ff40
(I'm also not sure that the error message is clear enough (can't we say
"relation X is not a partition of relation Y" in this context, as in
MarkInheritDetached(), for example?).)
Whilst with
ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
I get:
Program terminated with signal SIGSEGV, Segmentation fault.
#0 pg_detoast_datum_packed (datum=0x1) at fmgr.c:1866
1866 if (VARATT_IS_COMPRESSED(datum) || VARATT_IS_EXTERNAL(datum))
(gdb) bt
#0 pg_detoast_datum_packed (datum=0x1) at fmgr.c:1866
#1 0x000055d77d00fde2 in bttextcmp (...) at ../../../../src/include/postgres.h:314
#2 0x000055d77d03fa27 in FunctionCall2Coll (...) at fmgr.c:1161
#3 0x000055d77ce1572f in partition_rbound_cmp (...) at partbounds.c:3525
#4 0x000055d77ce157b9 in qsort_partition_rbound_cmp (...) at partbounds.c:3816
#5 0x000055d77d0982ef in qsort_arg (...) at ../../src/include/lib/sort_template.h:316
#6 0x000055d77ce1d109 in calculate_partition_bound_for_merge (...) at partbounds.c:5786
#7 0x000055d77cc24b2b in transformPartitionCmdForMerge (...) at parse_utilcmd.c:3524
#8 0x000055d77cc2b555 in transformAlterTableStmt (...) at parse_utilcmd.c:3812
#9 0x000055d77ccab17c in ATParseTransformCmd (...) at tablecmds.c:5650
#10 0x000055d77ccafd09 in ATExecCmd (...) at tablecmds.c:5589
...
Best regards,
Alexander
Alexander Lakhin, thanks for the problems you found!
Unfortunately I can't watch them immediately (event [1]https://pgconf.ru/2024 -- With best regards, Dmitry Koval).
I will try to start solving them in 12-14 hours.
[1]: https://pgconf.ru/2024 -- With best regards, Dmitry Koval
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi all,
I went through the MERGE/SPLIT partition codes today, thanks for the
works. I found some grammar errors:
i. in error messages(Users can see this grammar errors, not friendly).
ii. in codes comments
Alexander Korotkov <aekorotkov@gmail.com> 于2024年4月7日周日 06:23写道:
Hi, Dmitry!
On Fri, Apr 5, 2024 at 4:00 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:I've revised the patchset.
Thanks for the corrections (especially ddl.sgml).
Could you also look at a small optimization for the MERGE PARTITIONS
command (in a separate file
v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch, I wrote
about it in an email 2024-03-31 00:56:50)?Files v31-0001-*.patch, v31-0002-*.patch are the same as
v30-0001-*.patch, v30-0002-*.patch (after rebasing because patch stopped
applying due to changes in upstream).I've pushed 0001 and 0002. I didn't push 0003 for the following reasons.
1) This doesn't keep functionality equivalent to 0001. With 0003, the
merged partition will inherit indexes, constraints, and so on from the
one of merging partitions.
2) This is not necessarily an optimization. Without 0003 indexes on
the merged partition are created after moving the rows in
attachPartitionTable(). With 0003 we merge data into the existing
partition which saves its indexes. That might cause a significant
performance loss because mass inserts into indexes may be much slower
than building indexes from scratch.
I think both aspects need to be carefully considered. Even if we
accept them, this needs to be documented. I think now it's too late
for both of these. So, this should wait for v18.------
Regards,
Alexander Korotkov
--
Tender Wang
OpenPie: https://en.openpie.com/
Attachments:
0001-Fix-some-grammer-errors-from-error-messages-and-code.patchapplication/octet-stream; name=0001-Fix-some-grammer-errors-from-error-messages-and-code.patchDownload
From 2b0fff52002df8e4dc35c7b50d2ffa9e302b50d7 Mon Sep 17 00:00:00 2001
From: "tender.wang" <tender.wang@openpie.com>
Date: Mon, 8 Apr 2024 18:35:05 +0800
Subject: [PATCH] Fix some grammer errors from error messages and codes
comments.
---
src/backend/commands/tablecmds.c | 18 +++++++++---------
src/backend/parser/parse_utilcmd.c | 2 +-
src/backend/partitioning/partbounds.c | 6 +++---
src/include/nodes/parsenodes.h | 2 +-
4 files changed, 14 insertions(+), 14 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 582890a302..2b0b594d75 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -19086,7 +19086,7 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
/*
- * attachPartitionTable: attach new partition to partitioned table
+ * attachPartitionTable: attach a new partition to the partitioned table
*
* wqueue: the ALTER TABLE work queue; can be NULL when not running as part
* of an ALTER TABLE sequence.
@@ -20879,10 +20879,10 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
*/
typedef struct SplitPartitionContext
{
- ExprState *partqualstate; /* expression for check slot for partition
+ ExprState *partqualstate; /* expression for checking slot for partition
* (NULL for DEFAULT partition) */
BulkInsertState bistate; /* state of bulk inserts for partition */
- TupleTableSlot *dstslot; /* slot for insert row into partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
Relation partRel; /* relation for partition */
} SplitPartitionContext;
@@ -21129,7 +21129,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
}
/*
- * createPartitionTable: create table for new partition with given name
+ * createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
* Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
@@ -21206,7 +21206,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* We are going to detach and remove this partition: need to use exclusive
- * lock for prevent DML-queries to the partition.
+ * lock for preventing DML-queries to the partition.
*/
splitRel = table_openrv(cmd->name, AccessExclusiveLock);
@@ -21256,13 +21256,13 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* If new partition has the same name as split partition then we should
- * rename split partition for reuse name.
+ * rename split partition for reusing name.
*/
if (isSameName)
{
/*
* We must bump the command counter to make the split partition tuple
- * visible for rename.
+ * visible for renaming.
*/
CommandCounterIncrement();
/* Rename partition. */
@@ -21271,7 +21271,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* We must bump the command counter to make the split partition tuple
- * visible after rename.
+ * visible after renaming.
*/
CommandCounterIncrement();
}
@@ -21446,7 +21446,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* We are going to detach and remove this partition: need to use
- * exclusive lock for prevent DML-queries to the partition.
+ * exclusive lock for preventing DML-queries to the partition.
*/
mergingPartition = table_openrv(name, AccessExclusiveLock);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 88a4a41186..9e3e14087f 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3804,7 +3804,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
if (list_length(partcmd->partlist) < 2)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("list of new partitions should contains at least two items")));
+ errmsg("list of new partitions should contain at least two items")));
if (cmd->subtype == AT_SplitPartition)
transformPartitionCmdForSplit(&cxt, partcmd);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c36e26ba4b..83df89e9b1 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4986,7 +4986,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * second_bound. These bounds should be equal 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
@@ -5262,7 +5262,7 @@ check_partition_bounds_for_split_range(Relation parent,
errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
first ? "lower" : "upper",
relname,
- defaultPart ? (first ? "less than" : "greater than") : "not equals to",
+ defaultPart ? (first ? "less than" : "greater than") : "not equal to",
first ? "lower" : "upper"),
parser_errposition(pstate, datum->location)));
}
@@ -5483,7 +5483,7 @@ check_parent_values_in_new_partitions(Relation parent,
Const *notFoundVal;
if (!searchNull)
- /* Make Const for get string representation of not found value. */
+ /* Make Const for getting string representation of not found value. */
notFoundVal = makeConst(key->parttypid[0],
key->parttypmod[0],
key->parttypcoll[0],
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 01fa1a6c2e..32df680a9a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -956,7 +956,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
+ List *partlist; /* list of partitions, for MERGE/SPLIT PARTITION
* command */
bool concurrent;
} PartitionCmd;
--
2.25.1
Hi Tender Wang,
08.04.2024 13:43, Tender Wang wrote:
Hi all,
I went through the MERGE/SPLIT partition codes today, thanks for the works. I found some grammar errors:
i. in error messages(Users can see this grammar errors, not friendly).
ii. in codes comments
On a quick glance, I saw also:
NULL-value
partitionde
splited
temparary
And a trailing whitespace at:
the quarter partition back to monthly partitions:
warning: 1 line adds whitespace errors.
I'm also confused by "administrators" here:
https://www.postgresql.org/docs/devel/ddl-partitioning.html
(We can find on the same page, for instance:
... whereas table inheritance allows data to be divided in a manner of
the user's choosing.
It seems to me, that "users" should work for merging partitions as well.)
Though the documentation addition requires more than just a quick glance,
of course.
Best regards,
Alexander
Hi!
Attached fix for the problems found by Alexander Lakhin.
About grammar errors.
Unfortunately, I don't know English well.
Therefore, I plan (in the coming days) to show the text to specialists
who perform technical translation of documentation.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v1-0001-Fixes-for-ALTER-TABLE-.-SPLIT-MERGE-PARTITIONS-.-.patchtext/plain; charset=UTF-8; name=v1-0001-Fixes-for-ALTER-TABLE-.-SPLIT-MERGE-PARTITIONS-.-.patchDownload
From 578b3fae50baffa3626570447d55ce4177fc6e7d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 8 Apr 2024 23:10:52 +0300
Subject: [PATCH v1] Fixes for ALTER TABLE ... SPLIT/MERGE PARTITIONS ...
commands
---
doc/src/sgml/ddl.sgml | 2 +-
src/backend/commands/tablecmds.c | 12 ------
src/backend/parser/parse_utilcmd.c | 38 +++++++++++++++++++
src/test/regress/expected/partition_merge.out | 29 +++++++++++---
src/test/regress/expected/partition_split.out | 13 +++++++
src/test/regress/sql/partition_merge.sql | 24 ++++++++++--
src/test/regress/sql/partition_split.sql | 15 ++++++++
7 files changed, 111 insertions(+), 22 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 8ff9a520ca..cd8304ef75 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4410,7 +4410,7 @@ ALTER TABLE measurement
this operation is not supported for hash-partitioned tables and acquires
an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
systems due to the lock's restrictive nature. For example, we can split
- the quarter partition back to monthly partitions:
+ the quarter partition back to monthly partitions:
<programlisting>
ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
(PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 865c6331c1..8a98a0af48 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21223,12 +21223,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
splitRel = table_openrv(cmd->name, AccessExclusiveLock);
- if (splitRel->rd_rel->relkind != RELKIND_RELATION)
- ereport(ERROR,
- (errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot split non-table partition \"%s\"",
- RelationGetRelationName(splitRel))));
-
splitRelOid = RelationGetRelid(splitRel);
/* Check descriptions of new partitions. */
@@ -21463,12 +21457,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
mergingPartition = table_openrv(name, AccessExclusiveLock);
- if (mergingPartition->rd_rel->relkind != RELKIND_RELATION)
- ereport(ERROR,
- (errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot merge non-table partition \"%s\"",
- RelationGetRelationName(mergingPartition))));
-
/*
* Checking that two partitions have the same name was before, in
* function transformPartitionCmdForMerge().
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 9e3e14087f..0d5ed0079c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -3415,6 +3416,38 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition: check that partRelOid is partition of rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ relation_close(partRel, AccessShareLock);
+}
+
/*
* transformPartitionCmdForSplit
* Analyze the ALTER TABLLE ... SPLIT PARTITION command
@@ -3447,6 +3480,8 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+ checkPartition(parent, splitPartOid);
+
/* Then we should check partitions with transformed bounds. */
check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
}
@@ -3509,6 +3544,9 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOid = RangeVarGetRelid(name, NoLock, false);
if (partOid == defaultPartOid)
isDefaultPart = true;
+
+ checkPartition(parent, partOid);
+
partOids = lappend_oid(partOids, partOid);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2ba0ec47d9..60eacf6bf3 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
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"
+-- ERROR: "sales_apr2022" is not a table
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: "sales_apr2022" is not a table
-- 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;
@@ -590,12 +590,12 @@ CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Oslo', 'St. Pe
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
+-- ERROR: "sales_external" is not a partition
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
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
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: "sales_external2" is not a partition
-- 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"
@@ -729,4 +729,21 @@ SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
RESET enable_seqscan;
DROP TABLE sales_list;
--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 675a1453c3..26a0d09969 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1414,4 +1414,17 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index bb461e6623..9afed70365 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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"
+-- ERROR: "sales_apr2022" is not a table
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)
@@ -350,9 +350,9 @@ 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
+-- ERROR: "sales_external" is not a partition
ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
--- ERROR: partition bound for relation "sales_external2" is null
+-- ERROR: "sales_external2" is not a partition
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;
@@ -426,5 +426,23 @@ RESET enable_seqscan;
DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 8864f6ddaa..625b01ddd1 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -829,5 +829,20 @@ SELECT * FROM sales_others;
DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
On Mon, Apr 8, 2024 at 11:43 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Attached fix for the problems found by Alexander Lakhin.
About grammar errors.
Unfortunately, I don't know English well.
Therefore, I plan (in the coming days) to show the text to specialists
who perform technical translation of documentation.
Thank you. I've pushed this fix with minor corrections from me.
------
Regards,
Alexander Korotkov
Hello Alexander and Dmitry,
10.04.2024 02:03, Alexander Korotkov wrote:
On Mon, Apr 8, 2024 at 11:43 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Attached fix for the problems found by Alexander Lakhin.
About grammar errors.
Unfortunately, I don't know English well.
Therefore, I plan (in the coming days) to show the text to specialists
who perform technical translation of documentation.Thank you. I've pushed this fix with minor corrections from me.
Thank you for fixing that defect!
Please look at an error message emitted for foreign tables:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE FOREIGN TABLE ftp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1)
SERVER loopback OPTIONS (table_name 'lt_0_1');
CREATE FOREIGN TABLE ftp_1_2 PARTITION OF t
FOR VALUES FROM (1) TO (2)
SERVER loopback OPTIONS (table_name 'lt_1_2');
ALTER TABLE t MERGE PARTITIONS (ftp_0_1, ftp_1_2) INTO ftp_0_2;
ERROR: "ftp_0_1" is not a table
Shouldn't it be more correct/precise?
Best regards,
Alexander
10.04.2024 12:00, Alexander Lakhin wrote:
Hello Alexander and Dmitry,
10.04.2024 02:03, Alexander Korotkov wrote:
Thank you. I've pushed this fix with minor corrections from me.
Please look at another anomaly with MERGE.
CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t
FOR VALUES FROM (0) TO (2);
fails with
ERROR: cannot create a permanent relation as partition of temporary relation "t"
But
CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
CREATE TEMP TABLE tp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1);
CREATE TEMP TABLE tp_1_2 PARTITION OF t
FOR VALUES FROM (1) TO (2);
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
succeeds and we get:
regression=# \d+ t*
Partitioned table "pg_temp_1.t"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain | | |
Partition key: RANGE (i)
Partitions: tp_0_2 FOR VALUES FROM (0) TO (2)
Table "public.tp_0_2"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain | | |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
Best regards,
Alexander
Hi!
Alexander Korotkov, thanks for the commit of previous fix.
Alexander Lakhin, thanks for the problem you found.
There are two corrections attached to the letter:
1) v1-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch - fix
for the problem [1]/messages/by-id/dbc8b96c-3cf0-d1ee-860d-0e491da20485@gmail.com.
2) v1-0002-Fixes-for-english-text.patch - fixes for English text
(comments, error messages etc.).
Links:
[1]: /messages/by-id/dbc8b96c-3cf0-d1ee-860d-0e491da20485@gmail.com
/messages/by-id/dbc8b96c-3cf0-d1ee-860d-0e491da20485@gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v1-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchtext/plain; charset=UTF-8; name=v1-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From 3c443a57c334c74e9218fd4e2f1ced45e6d4141d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v1 1/2] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 11 ++++---
src/backend/parser/parse_utilcmd.c | 2 +-
src/test/regress/expected/partition_merge.out | 32 +++++++++++++++++--
src/test/regress/expected/partition_split.out | 29 +++++++++++++++++
src/test/regress/sql/partition_merge.sql | 24 +++++++++++++-
src/test/regress/sql/partition_split.sql | 23 +++++++++++++
6 files changed, 113 insertions(+), 8 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8a98a0af48..3da9f6389d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21145,17 +21145,19 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ newPartName->relpersistence = rel->rd_rel->relpersistence;
+
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
createStmt->tableElts = NIL;
@@ -21291,7 +21293,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
+ createPartitionTable(rel, sps->name, parentName, context);
/* Open the new partition and acquire exclusive lock on it. */
newPartRel = table_openrv(sps->name, AccessExclusiveLock);
@@ -21491,7 +21493,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
}
- createPartitionTable(mergePartName,
+ createPartitionTable(rel,
+ mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba069905..ef1a2a97c0 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3430,7 +3430,7 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not a ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf3..c69a717aaa 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not a ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not a ordinary table
-- 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;
@@ -746,4 +746,32 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d09969..3d22083e41 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365..cce5ffa29f 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not a ordinary table
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)
@@ -444,5 +444,27 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1..5dc2fc39cd 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v1-0002-Fixes-for-english-text.patchtext/plain; charset=UTF-8; name=v1-0002-Fixes-for-english-text.patchDownload
From ecbcbf622ae54bfeee7b92759058a117169dca5b Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 19:55:18 +0300
Subject: [PATCH v1 2/2] Fixes for english text
---
doc/src/sgml/ddl.sgml | 2 +-
doc/src/sgml/ref/alter_table.sgml | 6 +--
src/backend/commands/tablecmds.c | 18 +++----
src/backend/parser/parse_utilcmd.c | 6 +--
src/backend/partitioning/partbounds.c | 28 +++++------
src/test/isolation/specs/partition-merge.spec | 2 +-
src/test/regress/expected/partition_merge.out | 14 +++---
src/test/regress/expected/partition_split.out | 50 +++++++++----------
src/test/regress/sql/partition_merge.sql | 12 ++---
src/test/regress/sql/partition_split.sql | 42 ++++++++--------
10 files changed, 90 insertions(+), 90 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 00f44f56fa..026bfff70f 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4387,7 +4387,7 @@ ALTER INDEX measurement_city_id_logdate_key
a single partition using the
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
- administrators to combine partitions that are no longer needed as
+ users to combine partitions that are no longer needed as
separate entities. It's important to note that this operation is not
supported for hash-partitioned tables and acquires an
<literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8f5bf185dd..fe36ff82e5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1175,7 +1175,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables is necessary that the ranges
+ For range-partitioned tables it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
be merged into one range without spaces and overlaps (otherwise an error
@@ -1185,10 +1185,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For list-partitioned tables the values lists of all partitions
+ For list-partitioned tables the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form a list of values of partition
+ combined and form the list of values of partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3da9f6389d..c44d9c1db6 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20888,7 +20888,7 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
/*
- * Struct with context of new partition for insert rows from splited partition
+ * Struct with context of new partition for inserting rows from split partition
*/
typedef struct SplitPartitionContext
{
@@ -20945,7 +20945,7 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
*
* New partitions description:
* partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * newPartRels: list of Relations.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -21030,7 +21030,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
+ * (for first new partition, but other new partitions can use the same
* map).
*/
pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
@@ -21085,7 +21085,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
}
else
@@ -21245,7 +21245,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
/*
- * This would fail later on anyway, if the relation already exists.
+ * This would fail later on anyway if the relation already exists.
* But by catching it here we can emit a nicer error message.
*/
existing_relid = get_relname_relid(relname, namespaceId);
@@ -21312,7 +21312,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel = (Relation) lfirst(listptr2);
- /* wqueue = NULL: verification for each cloned constraint is not need. */
+ /* wqueue = NULL: verification for each cloned constraint is not needed. */
attachPartitionTable(NULL, rel, newPartRel, sps->bound);
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
@@ -21386,7 +21386,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
}
else
@@ -21488,7 +21488,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
if (isSameName)
{
- /* Create partition table with generated temparary name. */
+ /* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
@@ -21512,7 +21512,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* Attach a new partition to the partitioned table. wqueue = NULL:
- * verification for each cloned constraint is not need.
+ * verification for each cloned constraint is not needed.
*/
attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ef1a2a97c0..82b6ba7fc6 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3492,7 +3492,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
*
- * Does simple checks for merged partitions. Calculates bound of result
+ * Does simple checks for merged partitions. Calculates bound of resulting
* partition.
*/
static void
@@ -3537,7 +3537,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (equal(name, name2))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("partition with name \"%s\" already used", name->relname)),
+ errmsg("partition with name \"%s\" is already used", name->relname)),
parser_errposition(cxt->pstate, name2->location));
}
@@ -3551,7 +3551,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOids = lappend_oid(partOids, partOid);
}
- /* Allocate bound of result partition. */
+ /* Allocate bound of resulting partition. */
Assert(partcmd->bound == NULL);
partcmd->bound = makeNode(PartitionBoundSpec);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c0c49b0a0b..1c8396e83c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,7 +3214,7 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
+ * Point to problematic key in the list of lower datums;
* if we have equality, point to the first one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
@@ -4986,10 +4986,10 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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 equal except case
+ * second_bound. These bounds should be equal except when
* "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
+ * second_bound because space between these bounds will be included in
* DEFAULT partition.
*
* parent: partitioned table
@@ -4998,7 +4998,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
@@ -5020,7 +5020,7 @@ check_two_partitions_bounds_range(Relation parent,
second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true);
/*
- * lower1=false (the second to last argument) for correct comparison lower
+ * lower1=false (the second to last argument) for correct comparison of lower
* and upper bounds.
*/
cmpval = partition_rbound_cmp(key->partnatts,
@@ -5140,7 +5140,7 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
*
* (function for BY RANGE partitioning)
*
- * Checks that bounds of new partition "spec" is inside bounds of split
+ * Checks that bounds of new partition "spec" are inside bounds of split
* partition (with Oid splitPartOid). If first=true (this means that "spec" is
* the first of new partitions) then lower bound of "spec" should be equal (or
* greater than or equal in case defaultPart=true) to lower bound of split
@@ -5274,7 +5274,7 @@ check_partition_bounds_for_split_range(Relation parent,
*
* (function for BY LIST partitioning)
*
- * Checks that bounds of new partition is inside bounds of split partition
+ * Checks that bounds of new partition are inside bounds of split partition
* (with Oid splitPartOid).
*
* parent: partitioned table
@@ -5445,8 +5445,8 @@ check_parent_values_in_new_partitions(Relation parent,
Assert(key->strategy == PARTITION_STRATEGY_LIST);
/*
- * Special processing for NULL value. Search NULL-value if it contains
- * split partition (partOid).
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
*/
if (partition_bound_accepts_nulls(boundinfo) &&
partdesc->oids[boundinfo->null_index] == partOid)
@@ -5461,7 +5461,7 @@ check_parent_values_in_new_partitions(Relation parent,
/*
* Search all values of split partition with partOid in PartitionDesc of
- * partitionde table.
+ * partitioned table.
*/
for (i = 0; i < boundinfo->ndatums; i++)
{
@@ -5498,7 +5498,7 @@ check_parent_values_in_new_partitions(Relation parent,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions not have value %s but split partition has",
+ errmsg("new partitions do not have value %s but split partition has",
searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
}
}
@@ -5714,7 +5714,7 @@ check_partitions_for_split(Relation parent,
if (equal(sps->name, sps2->name))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" already used", sps2->name->relname)),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
parser_errposition(pstate, sps2->name->location));
}
}
@@ -5805,14 +5805,14 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * Lower bound of first partition is a lower bound of merged
+ * Lower bound of first partition is the 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
+ * Upper bound of last partition is the upper bound of merged
* partition.
*/
spec->upperdatums =
diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec
index ec48732c58..dc2b9d3445 100644
--- a/src/test/isolation/specs/partition-merge.spec
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -38,7 +38,7 @@ 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
+# s2 is trying to update inserted row and waits until s1 finishes
# MERGE operation.
permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index c69a717aaa..6e25365124 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -20,19 +20,19 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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
+-- ERROR: partition with name "sales_feb2022" is 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
+ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
-- ERROR: "sales_apr2022" is not a ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not a ordinary table
--- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
@@ -52,7 +52,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -162,7 +162,7 @@ SELECT * FROM sales_others;
14 | Smith | 510 | 05-04-2022
(1 row)
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
@@ -704,7 +704,7 @@ SELECT * FROM sales_all;
13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3d22083e41..87417b7796 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -43,7 +43,7 @@ ERROR: empty range bound specified for partition "sales_mar2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
^
DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
ERROR: list of new partitions should contain at least two items
@@ -55,21 +55,21 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" already used
+ERROR: name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" already used
+ERROR: name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -96,7 +96,7 @@ LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -191,7 +191,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -394,7 +394,7 @@ LINE 1: SELECT * FROM sales_jan_feb2022;
^
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -441,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
@@ -503,7 +503,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -537,7 +537,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -555,7 +555,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
^
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -564,7 +564,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -629,7 +629,7 @@ INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -770,11 +770,11 @@ DROP TABLE salesmans CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
@@ -793,7 +793,7 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
salesman_name | |
(2 rows)
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -1063,8 +1063,8 @@ LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -1075,18 +1075,18 @@ CREATE TABLE sales_list
PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition has
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions not have value NULL but split partition has
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value NULL but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition has
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value 'Kyiv' but split partition has
DROP TABLE sales_list;
--
-- Test: BY LIST partitioning, SPLIT PARTITION with data
@@ -1174,7 +1174,7 @@ SELECT * FROM sales_central;
13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index cce5ffa29f..c96120a4ad 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -26,14 +26,14 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- ERROR: partition with name "sales_feb2022" already used
+-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not a ordinary table
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
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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;
@@ -48,7 +48,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -96,7 +96,7 @@ SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb_mar_apr2022;
SELECT * FROM sales_others;
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -415,7 +415,7 @@ SELECT * FROM sales_list;
SELECT * FROM sales_nord;
SELECT * FROM sales_all;
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 5dc2fc39cd..763699c5af 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -42,7 +42,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
@@ -52,14 +52,14 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -77,7 +77,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -133,7 +133,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -219,7 +219,7 @@ SELECT * FROM sales_jan_feb2022;
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -250,7 +250,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
@@ -270,7 +270,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -299,7 +299,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -313,7 +313,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -325,7 +325,7 @@ DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -372,7 +372,7 @@ DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -470,12 +470,12 @@ DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
@@ -484,7 +484,7 @@ INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
@@ -631,8 +631,8 @@ DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -645,13 +645,13 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition has
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition has
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
@@ -703,7 +703,7 @@ SELECT * FROM sales_east;
SELECT * FROM sales_nord;
SELECT * FROM sales_central;
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
--
2.40.1.windows.1
On Thu, Apr 11, 2024 at 1:22 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
2) v1-0002-Fixes-for-english-text.patch - fixes for English text
(comments, error messages etc.).
FWIW, I also proposed a patch earlier that fixes error messages and
comments in the split partition code at
/messages/by-id/CAMbWs49DDsknxyoycBqiE72VxzL_sYHF6zqL8dSeNehKPJhkKg@mail.gmail.com
Thanks
Richard
Hi!
FWIW, I also proposed a patch earlier that fixes error messages and
comments in the split partition code
Sorry, I thought all the fixes you suggested were already included in
v1-0002-Fixes-for-english-text.patch (but they are not).
Added missing lines to v2-0002-Fixes-for-english-text.patch.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v2-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchtext/plain; charset=UTF-8; name=v2-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From cfd5a56d15e7ead6dd7ae66cd382de3fa38150d7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v2 1/2] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 11 ++++---
src/backend/parser/parse_utilcmd.c | 2 +-
src/test/regress/expected/partition_merge.out | 32 +++++++++++++++++--
src/test/regress/expected/partition_split.out | 29 +++++++++++++++++
src/test/regress/sql/partition_merge.sql | 24 +++++++++++++-
src/test/regress/sql/partition_split.sql | 23 +++++++++++++
6 files changed, 113 insertions(+), 8 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8a98a0af48..3da9f6389d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21145,17 +21145,19 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ newPartName->relpersistence = rel->rd_rel->relpersistence;
+
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
createStmt->tableElts = NIL;
@@ -21291,7 +21293,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
+ createPartitionTable(rel, sps->name, parentName, context);
/* Open the new partition and acquire exclusive lock on it. */
newPartRel = table_openrv(sps->name, AccessExclusiveLock);
@@ -21491,7 +21493,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
}
- createPartitionTable(mergePartName,
+ createPartitionTable(rel,
+ mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba069905..a3bbcc99c0 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3430,7 +3430,7 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not an ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf3..9fe97a801d 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not an ordinary table
-- 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;
@@ -746,4 +746,32 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d09969..3d22083e41 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365..428b6cc88f 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
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)
@@ -444,5 +444,27 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1..5dc2fc39cd 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v2-0002-Fixes-for-english-text.patchtext/plain; charset=UTF-8; name=v2-0002-Fixes-for-english-text.patchDownload
From 83cd86343b8a75afe89e4177fc064e53fe821b01 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 19:55:18 +0300
Subject: [PATCH v2 2/2] Fixes for english text
---
doc/src/sgml/ddl.sgml | 2 +-
doc/src/sgml/ref/alter_table.sgml | 6 +-
src/backend/commands/tablecmds.c | 18 +++---
src/backend/parser/parse_utilcmd.c | 6 +-
src/backend/partitioning/partbounds.c | 30 +++++-----
src/test/isolation/specs/partition-merge.spec | 2 +-
src/test/regress/expected/partition_merge.out | 14 ++---
src/test/regress/expected/partition_split.out | 58 +++++++++----------
src/test/regress/sql/partition_merge.sql | 12 ++--
src/test/regress/sql/partition_split.sql | 48 +++++++--------
10 files changed, 98 insertions(+), 98 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 00f44f56fa..026bfff70f 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4387,7 +4387,7 @@ ALTER INDEX measurement_city_id_logdate_key
a single partition using the
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
- administrators to combine partitions that are no longer needed as
+ users to combine partitions that are no longer needed as
separate entities. It's important to note that this operation is not
supported for hash-partitioned tables and acquires an
<literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8f5bf185dd..fe36ff82e5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1175,7 +1175,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables is necessary that the ranges
+ For range-partitioned tables it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
be merged into one range without spaces and overlaps (otherwise an error
@@ -1185,10 +1185,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For list-partitioned tables the values lists of all partitions
+ For list-partitioned tables the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form a list of values of partition
+ combined and form the list of values of partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3da9f6389d..c44d9c1db6 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20888,7 +20888,7 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
/*
- * Struct with context of new partition for insert rows from splited partition
+ * Struct with context of new partition for inserting rows from split partition
*/
typedef struct SplitPartitionContext
{
@@ -20945,7 +20945,7 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
*
* New partitions description:
* partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * newPartRels: list of Relations.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -21030,7 +21030,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
+ * (for first new partition, but other new partitions can use the same
* map).
*/
pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
@@ -21085,7 +21085,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
}
else
@@ -21245,7 +21245,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
/*
- * This would fail later on anyway, if the relation already exists.
+ * This would fail later on anyway if the relation already exists.
* But by catching it here we can emit a nicer error message.
*/
existing_relid = get_relname_relid(relname, namespaceId);
@@ -21312,7 +21312,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel = (Relation) lfirst(listptr2);
- /* wqueue = NULL: verification for each cloned constraint is not need. */
+ /* wqueue = NULL: verification for each cloned constraint is not needed. */
attachPartitionTable(NULL, rel, newPartRel, sps->bound);
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
@@ -21386,7 +21386,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
}
else
@@ -21488,7 +21488,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
if (isSameName)
{
- /* Create partition table with generated temparary name. */
+ /* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
@@ -21512,7 +21512,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/*
* Attach a new partition to the partitioned table. wqueue = NULL:
- * verification for each cloned constraint is not need.
+ * verification for each cloned constraint is not needed.
*/
attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index a3bbcc99c0..1f6e90cd47 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3492,7 +3492,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
*
- * Does simple checks for merged partitions. Calculates bound of result
+ * Does simple checks for merged partitions. Calculates bound of resulting
* partition.
*/
static void
@@ -3537,7 +3537,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (equal(name, name2))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("partition with name \"%s\" already used", name->relname)),
+ errmsg("partition with name \"%s\" is already used", name->relname)),
parser_errposition(cxt->pstate, name2->location));
}
@@ -3551,7 +3551,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOids = lappend_oid(partOids, partOid);
}
- /* Allocate bound of result partition. */
+ /* Allocate bound of resulting partition. */
Assert(partcmd->bound == NULL);
partcmd->bound = makeNode(PartitionBoundSpec);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c0c49b0a0b..f89bdb3c86 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,7 +3214,7 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
+ * Point to problematic key in the list of lower datums;
* if we have equality, point to the first one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
@@ -4986,10 +4986,10 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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 equal except case
+ * second_bound. These bounds should be equal except when
* "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
+ * second_bound because space between these bounds will be included in
* DEFAULT partition.
*
* parent: partitioned table
@@ -4998,7 +4998,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
@@ -5020,7 +5020,7 @@ check_two_partitions_bounds_range(Relation parent,
second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true);
/*
- * lower1=false (the second to last argument) for correct comparison lower
+ * lower1=false (the second to last argument) for correct comparison of lower
* and upper bounds.
*/
cmpval = partition_rbound_cmp(key->partnatts,
@@ -5140,7 +5140,7 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
*
* (function for BY RANGE partitioning)
*
- * Checks that bounds of new partition "spec" is inside bounds of split
+ * Checks that bounds of new partition "spec" are inside bounds of split
* partition (with Oid splitPartOid). If first=true (this means that "spec" is
* the first of new partitions) then lower bound of "spec" should be equal (or
* greater than or equal in case defaultPart=true) to lower bound of split
@@ -5274,7 +5274,7 @@ check_partition_bounds_for_split_range(Relation parent,
*
* (function for BY LIST partitioning)
*
- * Checks that bounds of new partition is inside bounds of split partition
+ * Checks that bounds of new partition are inside bounds of split partition
* (with Oid splitPartOid).
*
* parent: partitioned table
@@ -5445,8 +5445,8 @@ check_parent_values_in_new_partitions(Relation parent,
Assert(key->strategy == PARTITION_STRATEGY_LIST);
/*
- * Special processing for NULL value. Search NULL-value if it contains
- * split partition (partOid).
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
*/
if (partition_bound_accepts_nulls(boundinfo) &&
partdesc->oids[boundinfo->null_index] == partOid)
@@ -5461,7 +5461,7 @@ check_parent_values_in_new_partitions(Relation parent,
/*
* Search all values of split partition with partOid in PartitionDesc of
- * partitionde table.
+ * partitioned table.
*/
for (i = 0; i < boundinfo->ndatums; i++)
{
@@ -5498,7 +5498,7 @@ check_parent_values_in_new_partitions(Relation parent,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions not have value %s but split partition has",
+ errmsg("new partitions do not have value %s but split partition does",
searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
}
}
@@ -5645,7 +5645,7 @@ check_partitions_for_split(Relation parent,
{
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ errmsg("all partitions in the list should be DEFAULT because split partition is DEFAULT")),
parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
}
else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
@@ -5714,7 +5714,7 @@ check_partitions_for_split(Relation parent,
if (equal(sps->name, sps2->name))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" already used", sps2->name->relname)),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
parser_errposition(pstate, sps2->name->location));
}
}
@@ -5805,14 +5805,14 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * Lower bound of first partition is a lower bound of merged
+ * Lower bound of first partition is the 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
+ * Upper bound of last partition is the upper bound of merged
* partition.
*/
spec->upperdatums =
diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec
index ec48732c58..dc2b9d3445 100644
--- a/src/test/isolation/specs/partition-merge.spec
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -38,7 +38,7 @@ 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
+# s2 is trying to update inserted row and waits until s1 finishes
# MERGE operation.
permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 9fe97a801d..26756faf38 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -20,19 +20,19 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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
+-- ERROR: partition with name "sales_feb2022" is 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
+ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not an ordinary table
--- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
@@ -52,7 +52,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -162,7 +162,7 @@ SELECT * FROM sales_others;
14 | Smith | 510 | 05-04-2022
(1 row)
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
@@ -704,7 +704,7 @@ SELECT * FROM sales_all;
13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3d22083e41..46f02013be 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -43,7 +43,7 @@ ERROR: empty range bound specified for partition "sales_mar2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
^
DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
ERROR: list of new partitions should contain at least two items
@@ -55,21 +55,21 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" already used
+ERROR: name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" already used
+ERROR: name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -96,7 +96,7 @@ LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -191,7 +191,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -394,7 +394,7 @@ LINE 1: SELECT * FROM sales_jan_feb2022;
^
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -441,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
@@ -503,7 +503,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -537,7 +537,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -547,15 +547,15 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
^
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
-ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
^
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -564,7 +564,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -616,7 +616,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
@@ -629,7 +629,7 @@ INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -770,11 +770,11 @@ DROP TABLE salesmans CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
@@ -793,7 +793,7 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
salesman_name | |
(2 rows)
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -1036,7 +1036,7 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -1063,8 +1063,8 @@ LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -1075,18 +1075,18 @@ CREATE TABLE sales_list
PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions not have value NULL but split partition has
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value 'Kyiv' but split partition does
DROP TABLE sales_list;
--
-- Test: BY LIST partitioning, SPLIT PARTITION with data
@@ -1174,7 +1174,7 @@ SELECT * FROM sales_central;
13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 428b6cc88f..99b8f11a18 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -26,14 +26,14 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- ERROR: partition with name "sales_feb2022" already used
+-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not an ordinary table
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
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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;
@@ -48,7 +48,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -96,7 +96,7 @@ SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb_mar_apr2022;
SELECT * FROM sales_others;
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -415,7 +415,7 @@ SELECT * FROM sales_list;
SELECT * FROM sales_nord;
SELECT * FROM sales_all;
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 5dc2fc39cd..576f9f0f63 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -42,7 +42,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
@@ -52,14 +52,14 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -77,7 +77,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -133,7 +133,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -219,7 +219,7 @@ SELECT * FROM sales_jan_feb2022;
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -250,7 +250,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
@@ -270,7 +270,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -299,7 +299,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -307,13 +307,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -325,7 +325,7 @@ DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -361,7 +361,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
@@ -372,7 +372,7 @@ DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -470,12 +470,12 @@ DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
@@ -484,7 +484,7 @@ INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
@@ -609,7 +609,7 @@ CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Pete
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -631,8 +631,8 @@ DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -645,13 +645,13 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
@@ -703,7 +703,7 @@ SELECT * FROM sales_east;
SELECT * FROM sales_nord;
SELECT * FROM sales_central;
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
--
2.40.1.windows.1
Hi Dmitry,
11.04.2024 11:59, Dmitry Koval wrote:
FWIW, I also proposed a patch earlier that fixes error messages and
comments in the split partition codeSorry, I thought all the fixes you suggested were already included in v1-0002-Fixes-for-english-text.patch (but they
are not).
Added missing lines to v2-0002-Fixes-for-english-text.patch.
It seems to me that v2-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch
is not complete either.
Take a look, please:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
SET search_path = pg_temp, public;
CREATE TABLE tp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1);
-- fails with:
ERROR: cannot create a temporary relation as partition of permanent relation "t"
But:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t
FOR VALUES FROM (1) TO (2);
INSERT INTO t VALUES(0), (1);
SELECT * FROM t;
-- the expected result is:
i
---
0
1
(2 rows)
SET search_path = pg_temp, public;
ALTER TABLE t
MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
-- succeeds, and
\c -
SELECT * FROM t;
-- gives:
i
---
(0 rows)
Please also ask your tech writers to check contents of src/test/sql/*, if
possible (perhaps, they'll fix "salesmans" and improve grammar).
Best regards,
Alexander
Hi!
1.
Alexander Lakhin sent a question about index name after MERGE (partition
name is the same as one of the merged partitions):
----start of quote----
I'm also confused by an index name after MERGE:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
\d+ t*
Table "public.tp_1_2"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
Indexes:
"merge-16385-3A14B2-tmp_i_idx" btree (i)
Is the name "merge-16385-3A14B2-tmp_i_idx" valid or it's something
temporary?
----end of quote----
Fix for this case added to file
v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
----
2.
It seems to me that v2-0001-Fix-for-SPLIT-MERGE-partitions-of-
temporary-table.patch is not complete either.
Added correction (and test), see
v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchtext/plain; charset=UTF-8; name=v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From 58eb4abd4f065b6aa423bbddf62acd1799eba22e Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v3 1/2] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 30 ++++---
src/backend/parser/parse_utilcmd.c | 2 +-
src/test/regress/expected/partition_merge.out | 87 ++++++++++++++++++-
src/test/regress/expected/partition_split.out | 29 +++++++
src/test/regress/sql/partition_merge.sql | 70 ++++++++++++++-
src/test/regress/sql/partition_split.sql | 23 +++++
6 files changed, 227 insertions(+), 14 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8a98a0af48..2769be55be 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21145,17 +21145,20 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ newPartName->relpersistence = rel->rd_rel->relpersistence;
+ newPartName->schemaname = modelRelName->schemaname;
+
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
createStmt->tableElts = NIL;
@@ -21291,7 +21294,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
+ createPartitionTable(rel, sps->name, parentName, context);
/* Open the new partition and acquire exclusive lock on it. */
newPartRel = table_openrv(sps->name, AccessExclusiveLock);
@@ -21491,7 +21494,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
}
- createPartitionTable(mergePartName,
+ createPartitionTable(rel,
+ mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21507,12 +21511,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21542,7 +21540,19 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
RenameRelationInternal(RelationGetRelid(newPartRel),
cmd->name->relname, false, false);
+ /*
+ * Bump the command counter to make the tuple of renamed partition
+ * visible for attach partition operation.
+ */
+ CommandCounterIncrement();
}
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba069905..a3bbcc99c0 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3430,7 +3430,7 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not an ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf3..9d48262a82 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not an ordinary table
-- 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;
@@ -746,4 +746,87 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+ indexname
+--------------
+ tp_1_2_i_idx
+(1 row)
+
+DROP TABLE t;
+--
+-- Try creating a partition in the temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, public;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition tp_0_2 should be permanent (p).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | p
+(1 row)
+
+SET search_path = public, pg_temp;
+DROP TABLE t;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d09969..3d22083e41 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365..312f0e49d3 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
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)
@@ -444,5 +444,73 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+
+DROP TABLE t;
+
+--
+-- Try creating a partition in the temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, public;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition tp_0_2 should be permanent (p).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = public, pg_temp;
+
+DROP TABLE t;
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1..5dc2fc39cd 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v3-0002-Fixes-for-english-text.patchtext/plain; charset=UTF-8; name=v3-0002-Fixes-for-english-text.patchDownload
From f80a240209810749d64203fd469552aab1864d48 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 19:55:18 +0300
Subject: [PATCH v3 2/2] Fixes for english text
---
doc/src/sgml/ddl.sgml | 2 +-
doc/src/sgml/ref/alter_table.sgml | 6 +-
src/backend/commands/tablecmds.c | 16 ++---
src/backend/parser/parse_utilcmd.c | 6 +-
src/backend/partitioning/partbounds.c | 30 +++++-----
src/test/isolation/specs/partition-merge.spec | 2 +-
src/test/regress/expected/partition_merge.out | 14 ++---
src/test/regress/expected/partition_split.out | 58 +++++++++----------
src/test/regress/sql/partition_merge.sql | 12 ++--
src/test/regress/sql/partition_split.sql | 48 +++++++--------
10 files changed, 97 insertions(+), 97 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 00f44f56fa..026bfff70f 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4387,7 +4387,7 @@ ALTER INDEX measurement_city_id_logdate_key
a single partition using the
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
- administrators to combine partitions that are no longer needed as
+ users to combine partitions that are no longer needed as
separate entities. It's important to note that this operation is not
supported for hash-partitioned tables and acquires an
<literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8f5bf185dd..fe36ff82e5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1175,7 +1175,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables is necessary that the ranges
+ For range-partitioned tables it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
be merged into one range without spaces and overlaps (otherwise an error
@@ -1185,10 +1185,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For list-partitioned tables the values lists of all partitions
+ For list-partitioned tables the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form a list of values of partition
+ combined and form the list of values of partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2769be55be..dff9ac9df1 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20888,7 +20888,7 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
/*
- * Struct with context of new partition for insert rows from splited partition
+ * Struct with context of new partition for inserting rows from split partition
*/
typedef struct SplitPartitionContext
{
@@ -20945,7 +20945,7 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
*
* New partitions description:
* partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * newPartRels: list of Relations.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -21030,7 +21030,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
+ * (for first new partition, but other new partitions can use the same
* map).
*/
pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
@@ -21085,7 +21085,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
}
else
@@ -21246,7 +21246,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
/*
- * This would fail later on anyway, if the relation already exists.
+ * This would fail later on anyway if the relation already exists.
* But by catching it here we can emit a nicer error message.
*/
existing_relid = get_relname_relid(relname, namespaceId);
@@ -21313,7 +21313,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel = (Relation) lfirst(listptr2);
- /* wqueue = NULL: verification for each cloned constraint is not need. */
+ /* wqueue = NULL: verification for each cloned constraint is not needed. */
attachPartitionTable(NULL, rel, newPartRel, sps->bound);
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
@@ -21387,7 +21387,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
}
else
@@ -21489,7 +21489,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
if (isSameName)
{
- /* Create partition table with generated temparary name. */
+ /* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
tmpRelName, -1);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index a3bbcc99c0..1f6e90cd47 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3492,7 +3492,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
*
- * Does simple checks for merged partitions. Calculates bound of result
+ * Does simple checks for merged partitions. Calculates bound of resulting
* partition.
*/
static void
@@ -3537,7 +3537,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (equal(name, name2))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("partition with name \"%s\" already used", name->relname)),
+ errmsg("partition with name \"%s\" is already used", name->relname)),
parser_errposition(cxt->pstate, name2->location));
}
@@ -3551,7 +3551,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOids = lappend_oid(partOids, partOid);
}
- /* Allocate bound of result partition. */
+ /* Allocate bound of resulting partition. */
Assert(partcmd->bound == NULL);
partcmd->bound = makeNode(PartitionBoundSpec);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c0c49b0a0b..f89bdb3c86 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,7 +3214,7 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
+ * Point to problematic key in the list of lower datums;
* if we have equality, point to the first one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
@@ -4986,10 +4986,10 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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 equal except case
+ * second_bound. These bounds should be equal except when
* "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
+ * second_bound because space between these bounds will be included in
* DEFAULT partition.
*
* parent: partitioned table
@@ -4998,7 +4998,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
@@ -5020,7 +5020,7 @@ check_two_partitions_bounds_range(Relation parent,
second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true);
/*
- * lower1=false (the second to last argument) for correct comparison lower
+ * lower1=false (the second to last argument) for correct comparison of lower
* and upper bounds.
*/
cmpval = partition_rbound_cmp(key->partnatts,
@@ -5140,7 +5140,7 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
*
* (function for BY RANGE partitioning)
*
- * Checks that bounds of new partition "spec" is inside bounds of split
+ * Checks that bounds of new partition "spec" are inside bounds of split
* partition (with Oid splitPartOid). If first=true (this means that "spec" is
* the first of new partitions) then lower bound of "spec" should be equal (or
* greater than or equal in case defaultPart=true) to lower bound of split
@@ -5274,7 +5274,7 @@ check_partition_bounds_for_split_range(Relation parent,
*
* (function for BY LIST partitioning)
*
- * Checks that bounds of new partition is inside bounds of split partition
+ * Checks that bounds of new partition are inside bounds of split partition
* (with Oid splitPartOid).
*
* parent: partitioned table
@@ -5445,8 +5445,8 @@ check_parent_values_in_new_partitions(Relation parent,
Assert(key->strategy == PARTITION_STRATEGY_LIST);
/*
- * Special processing for NULL value. Search NULL-value if it contains
- * split partition (partOid).
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
*/
if (partition_bound_accepts_nulls(boundinfo) &&
partdesc->oids[boundinfo->null_index] == partOid)
@@ -5461,7 +5461,7 @@ check_parent_values_in_new_partitions(Relation parent,
/*
* Search all values of split partition with partOid in PartitionDesc of
- * partitionde table.
+ * partitioned table.
*/
for (i = 0; i < boundinfo->ndatums; i++)
{
@@ -5498,7 +5498,7 @@ check_parent_values_in_new_partitions(Relation parent,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions not have value %s but split partition has",
+ errmsg("new partitions do not have value %s but split partition does",
searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
}
}
@@ -5645,7 +5645,7 @@ check_partitions_for_split(Relation parent,
{
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ errmsg("all partitions in the list should be DEFAULT because split partition is DEFAULT")),
parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
}
else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
@@ -5714,7 +5714,7 @@ check_partitions_for_split(Relation parent,
if (equal(sps->name, sps2->name))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" already used", sps2->name->relname)),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
parser_errposition(pstate, sps2->name->location));
}
}
@@ -5805,14 +5805,14 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * Lower bound of first partition is a lower bound of merged
+ * Lower bound of first partition is the 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
+ * Upper bound of last partition is the upper bound of merged
* partition.
*/
spec->upperdatums =
diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec
index ec48732c58..dc2b9d3445 100644
--- a/src/test/isolation/specs/partition-merge.spec
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -38,7 +38,7 @@ 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
+# s2 is trying to update inserted row and waits until s1 finishes
# MERGE operation.
permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 9d48262a82..39c3b90b9c 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -20,19 +20,19 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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
+-- ERROR: partition with name "sales_feb2022" is 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
+ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not an ordinary table
--- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
@@ -52,7 +52,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -162,7 +162,7 @@ SELECT * FROM sales_others;
14 | Smith | 510 | 05-04-2022
(1 row)
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
@@ -704,7 +704,7 @@ SELECT * FROM sales_all;
13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3d22083e41..46f02013be 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -43,7 +43,7 @@ ERROR: empty range bound specified for partition "sales_mar2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
^
DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
ERROR: list of new partitions should contain at least two items
@@ -55,21 +55,21 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" already used
+ERROR: name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" already used
+ERROR: name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -96,7 +96,7 @@ LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -191,7 +191,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -394,7 +394,7 @@ LINE 1: SELECT * FROM sales_jan_feb2022;
^
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -441,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
@@ -503,7 +503,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -537,7 +537,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -547,15 +547,15 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
^
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
-ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
^
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -564,7 +564,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -616,7 +616,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
@@ -629,7 +629,7 @@ INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -770,11 +770,11 @@ DROP TABLE salesmans CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
@@ -793,7 +793,7 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
salesman_name | |
(2 rows)
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -1036,7 +1036,7 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -1063,8 +1063,8 @@ LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -1075,18 +1075,18 @@ CREATE TABLE sales_list
PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions not have value NULL but split partition has
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value 'Kyiv' but split partition does
DROP TABLE sales_list;
--
-- Test: BY LIST partitioning, SPLIT PARTITION with data
@@ -1174,7 +1174,7 @@ SELECT * FROM sales_central;
13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 312f0e49d3..38cb60585d 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -26,14 +26,14 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- ERROR: partition with name "sales_feb2022" already used
+-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not an ordinary table
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
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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;
@@ -48,7 +48,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -96,7 +96,7 @@ SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb_mar_apr2022;
SELECT * FROM sales_others;
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -415,7 +415,7 @@ SELECT * FROM sales_list;
SELECT * FROM sales_nord;
SELECT * FROM sales_all;
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 5dc2fc39cd..576f9f0f63 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -42,7 +42,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
@@ -52,14 +52,14 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -77,7 +77,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -133,7 +133,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -219,7 +219,7 @@ SELECT * FROM sales_jan_feb2022;
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -250,7 +250,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
@@ -270,7 +270,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -299,7 +299,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -307,13 +307,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -325,7 +325,7 @@ DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -361,7 +361,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
@@ -372,7 +372,7 @@ DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -470,12 +470,12 @@ DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
@@ -484,7 +484,7 @@ INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
@@ -609,7 +609,7 @@ CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Pete
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -631,8 +631,8 @@ DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -645,13 +645,13 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
@@ -703,7 +703,7 @@ SELECT * FROM sales_east;
SELECT * FROM sales_nord;
SELECT * FROM sales_central;
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
--
2.40.1.windows.1
Hi, Dmitry!
On Thu, Apr 11, 2024 at 4:27 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
1.
Alexander Lakhin sent a question about index name after MERGE (partition
name is the same as one of the merged partitions):----start of quote----
I'm also confused by an index name after MERGE:
CREATE TABLE t (i int) PARTITION BY RANGE (i);CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
\d+ t*Table "public.tp_1_2"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
Indexes:
"merge-16385-3A14B2-tmp_i_idx" btree (i)Is the name "merge-16385-3A14B2-tmp_i_idx" valid or it's something
temporary?
----end of quote----Fix for this case added to file
v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.----
2.
It seems to me that v2-0001-Fix-for-SPLIT-MERGE-partitions-of-
temporary-table.patch is not complete either.Added correction (and test), see
v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
Thank you, I'll review this later today.
------
Regards,
Alexander Korotkov
11.04.2024 16:27, Dmitry Koval wrote:
Added correction (and test), see v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
Thank you for the correction, but may be an attempt to merge into implicit
pg_temp should fail just like CREATE TABLE ... PARTITION OF ... does?
Please look also at another anomaly with schemas:
CREATE SCHEMA s1;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t
FOR VALUES FROM (0) TO (2);
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION s1.tp0 FOR VALUES FROM (0) TO (1), PARTITION s1.tp1 FOR VALUES FROM (1) TO (2));
results in:
\d+ s1.*
Did not find any relation named "s1.*"
\d+ tp*
Table "public.tp0"
...
Table "public.tp1"
...
Best regards,
Alexander
On Thu, Apr 11, 2024 at 8:00 PM Alexander Lakhin <exclusion@gmail.com> wrote:
11.04.2024 16:27, Dmitry Koval wrote:
Added correction (and test), see v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
Thank you for the correction, but may be an attempt to merge into implicit
pg_temp should fail just like CREATE TABLE ... PARTITION OF ... does?Please look also at another anomaly with schemas:
CREATE SCHEMA s1;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t
FOR VALUES FROM (0) TO (2);
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION s1.tp0 FOR VALUES FROM (0) TO (1), PARTITION s1.tp1 FOR VALUES FROM (1) TO (2));
results in:
\d+ s1.*
Did not find any relation named "s1.*"
\d+ tp*
Table "public.tp0"
...
Table "public.tp1"
+1
I think we shouldn't unconditionally copy schema name and
relpersistence from the parent table. Instead we should throw the
error on a mismatch like CREATE TABLE ... PARTITION OF ... does. I'm
working on revising this fix.
------
Regards,
Alexander Korotkov
On Thu, Apr 11, 2024 at 9:54 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
I think we shouldn't unconditionally copy schema name and
relpersistence from the parent table. Instead we should throw the
error on a mismatch like CREATE TABLE ... PARTITION OF ... does. I'm
working on revising this fix.
We definitely shouldn't copy the schema name from the parent table. It
should be possible to schema-qualify the new partition names, and if
you don't, then the search_path should determine where they get
placed.
But I am inclined to think that relpersistence should be copied. It's
weird that you split an unlogged partition and you get logged
partitions.
One of the things I dislike about this type of feature -- not this
implementation specifically, but just this kind of idea in general --
is that the syntax mentions a whole bunch of tables but in a way where
you can't set their properties. Persistence, reloptions, whatever.
There's just no place to mention any of that stuff - and if you wanted
to create a place, you'd have to invent special syntax for each
separate thing. That's why I think it's good that the normal way of
creating a partition is CREATE TABLE .. PARTITION OF. Because that
way, we know that the full power of the CREATE TABLE statement is
always available, and you can set anything that you could set for a
table that is not a partition.
Of course, that is not to say that some people won't like to have a
feature of this sort. I expect they will. The approach does have some
drawbacks, though.
--
Robert Haas
EDB: http://www.enterprisedb.com
Hi!
Attached is a patch with corrections based on comments in previous
letters (I think these corrections are not final).
I'll be very grateful for feedbacks and bug reports.
11.04.2024 20:00, Alexander Lakhin wrote:
may be an attempt to merge into implicit
pg_temp should fail just like CREATE TABLE ... PARTITION OF ... does?
Corrected. Result is:
\d+ s1.*
Table "s1.tp0"
...
Table "s1.tp1"
...
\d+ tp*
Did not find any relation named "tp*".
12.04.2024 4:53, Alexander Korotkov wrote:
I think we shouldn't unconditionally copy schema name and
relpersistence from the parent table. Instead we should throw the
error on a mismatch like CREATE TABLE ... PARTITION OF ... does.
12.04.2024 5:20, Robert Haas wrote:
We definitely shouldn't copy the schema name from the parent table.
Fixed.
12.04.2024 5:20, Robert Haas wrote:
One of the things I dislike about this type of feature -- not this
implementation specifically, but just this kind of idea in general --
is that the syntax mentions a whole bunch of tables but in a way where
you can't set their properties. Persistence, reloptions, whatever.
In next releases I want to allow specifying options (probably, first of
all, specifying tablespace of the partitions).
But before that, I would like to get a users reaction - what options
they really need?
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v4-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchtext/plain; charset=UTF-8; name=v4-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From 707d15cf9ee4673a1deed2825f48ffbc09a34e9d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v4 1/2] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 32 +++--
src/backend/parser/parse_utilcmd.c | 19 ++-
src/test/regress/expected/partition_merge.out | 118 +++++++++++++++++-
src/test/regress/expected/partition_split.out | 29 +++++
src/test/regress/sql/partition_merge.sql | 95 +++++++++++++-
src/test/regress/sql/partition_split.sql | 23 ++++
6 files changed, 297 insertions(+), 19 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8a98a0af48..b59e1dda03 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21145,17 +21145,19 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ newPartName->relpersistence = rel->rd_rel->relpersistence;
+
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
createStmt->tableElts = NIL;
@@ -21291,7 +21293,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
+ createPartitionTable(rel, sps->name, parentName, context);
/* Open the new partition and acquire exclusive lock on it. */
newPartRel = table_openrv(sps->name, AccessExclusiveLock);
@@ -21488,10 +21490,10 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
/* 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);
+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
- createPartitionTable(mergePartName,
+ createPartitionTable(rel,
+ mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21507,12 +21509,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21542,7 +21538,19 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
RenameRelationInternal(RelationGetRelid(newPartRel),
cmd->name->relname, false, false);
+ /*
+ * Bump the command counter to make the tuple of renamed partition
+ * visible for attach partition operation.
+ */
+ CommandCounterIncrement();
}
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba069905..6b4dd81470 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3421,16 +3421,27 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
* Check that partRelOid is an oid of partition of the parent table rel
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, RangeVar *partName, Oid partRelOid)
{
Relation partRel;
+ Oid nspid;
+
+ nspid = RangeVarGetCreationNamespace(partName);
+
+ /* If the parent table is permanent, so must be all of its partitions. */
+ if (rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ isTempOrTempToastNamespace(nspid))
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(rel))));
partRel = relation_open(partRelOid, AccessShareLock);
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not an ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
@@ -3481,7 +3492,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
- checkPartition(parent, splitPartOid);
+ checkPartition(parent, partcmd->name, splitPartOid);
/* Then we should check partitions with transformed bounds. */
check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
@@ -3546,7 +3557,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (partOid == defaultPartOid)
isDefaultPart = true;
- checkPartition(parent, partOid);
+ checkPartition(parent, name, partOid);
partOids = lappend_oid(partOids, partOid);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf3..23fe99ba28 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not an ordinary table
-- 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;
@@ -746,4 +746,118 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+ indexname
+--------------
+ tp_1_2_i_idx
+(1 row)
+
+DROP TABLE t;
+--
+-- Try creating a partition of the permanent relation in a temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, public;
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = public, pg_temp;
+DROP TABLE t;
+RESET search_path;
+--
+-- Try creating a partition of the temporary relation in a permanent schema.
+--
+SET search_path = pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = public, pg_temp;
+-- There is no problem with creating a temporary partition in a permanent schema.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition tp_0_2 should be temporary (t).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+SET search_path = pg_temp, pg_temp;
+DROP TABLE t;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d09969..3d22083e41 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365..98738e165b 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
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)
@@ -444,5 +444,98 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+
+DROP TABLE t;
+
+--
+-- Try creating a partition of the permanent relation in a temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, public;
+
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = public, pg_temp;
+
+DROP TABLE t;
+RESET search_path;
+
+--
+-- Try creating a partition of the temporary relation in a permanent schema.
+--
+SET search_path = pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = public, pg_temp;
+
+-- There is no problem with creating a temporary partition in a permanent schema.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition tp_0_2 should be temporary (t).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, pg_temp;
+
+DROP TABLE t;
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1..5dc2fc39cd 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v4-0002-Fixes-for-english-text.patchtext/plain; charset=UTF-8; name=v4-0002-Fixes-for-english-text.patchDownload
From 1f34e2130bb836ef4cf847e8a40c79092fba77c7 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 19:55:18 +0300
Subject: [PATCH v4 2/2] Fixes for english text
---
doc/src/sgml/ddl.sgml | 2 +-
doc/src/sgml/ref/alter_table.sgml | 6 +-
src/backend/commands/tablecmds.c | 16 ++---
src/backend/parser/parse_utilcmd.c | 6 +-
src/backend/partitioning/partbounds.c | 30 +++++-----
src/test/isolation/specs/partition-merge.spec | 2 +-
src/test/regress/expected/partition_merge.out | 14 ++---
src/test/regress/expected/partition_split.out | 58 +++++++++----------
src/test/regress/sql/partition_merge.sql | 12 ++--
src/test/regress/sql/partition_split.sql | 48 +++++++--------
10 files changed, 97 insertions(+), 97 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 00f44f56fa..026bfff70f 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4387,7 +4387,7 @@ ALTER INDEX measurement_city_id_logdate_key
a single partition using the
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
- administrators to combine partitions that are no longer needed as
+ users to combine partitions that are no longer needed as
separate entities. It's important to note that this operation is not
supported for hash-partitioned tables and acquires an
<literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8f5bf185dd..fe36ff82e5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1175,7 +1175,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables is necessary that the ranges
+ For range-partitioned tables it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
be merged into one range without spaces and overlaps (otherwise an error
@@ -1185,10 +1185,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For list-partitioned tables the values lists of all partitions
+ For list-partitioned tables the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form a list of values of partition
+ combined and form the list of values of partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b59e1dda03..f58ff43699 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20888,7 +20888,7 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
/*
- * Struct with context of new partition for insert rows from splited partition
+ * Struct with context of new partition for inserting rows from split partition
*/
typedef struct SplitPartitionContext
{
@@ -20945,7 +20945,7 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
*
* New partitions description:
* partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * newPartRels: list of Relations.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -21030,7 +21030,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
+ * (for first new partition, but other new partitions can use the same
* map).
*/
pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
@@ -21085,7 +21085,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
}
else
@@ -21245,7 +21245,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
/*
- * This would fail later on anyway, if the relation already exists.
+ * This would fail later on anyway if the relation already exists.
* But by catching it here we can emit a nicer error message.
*/
existing_relid = get_relname_relid(relname, namespaceId);
@@ -21312,7 +21312,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel = (Relation) lfirst(listptr2);
- /* wqueue = NULL: verification for each cloned constraint is not need. */
+ /* wqueue = NULL: verification for each cloned constraint is not needed. */
attachPartitionTable(NULL, rel, newPartRel, sps->bound);
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
@@ -21386,7 +21386,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
}
else
@@ -21488,7 +21488,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
if (isSameName)
{
- /* Create partition table with generated temparary name. */
+ /* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6b4dd81470..361b31b7d3 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3503,7 +3503,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
*
- * Does simple checks for merged partitions. Calculates bound of result
+ * Does simple checks for merged partitions. Calculates bound of resulting
* partition.
*/
static void
@@ -3548,7 +3548,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (equal(name, name2))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("partition with name \"%s\" already used", name->relname)),
+ errmsg("partition with name \"%s\" is already used", name->relname)),
parser_errposition(cxt->pstate, name2->location));
}
@@ -3562,7 +3562,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOids = lappend_oid(partOids, partOid);
}
- /* Allocate bound of result partition. */
+ /* Allocate bound of resulting partition. */
Assert(partcmd->bound == NULL);
partcmd->bound = makeNode(PartitionBoundSpec);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c0c49b0a0b..f89bdb3c86 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,7 +3214,7 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
+ * Point to problematic key in the list of lower datums;
* if we have equality, point to the first one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
@@ -4986,10 +4986,10 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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 equal except case
+ * second_bound. These bounds should be equal except when
* "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
+ * second_bound because space between these bounds will be included in
* DEFAULT partition.
*
* parent: partitioned table
@@ -4998,7 +4998,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
@@ -5020,7 +5020,7 @@ check_two_partitions_bounds_range(Relation parent,
second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true);
/*
- * lower1=false (the second to last argument) for correct comparison lower
+ * lower1=false (the second to last argument) for correct comparison of lower
* and upper bounds.
*/
cmpval = partition_rbound_cmp(key->partnatts,
@@ -5140,7 +5140,7 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
*
* (function for BY RANGE partitioning)
*
- * Checks that bounds of new partition "spec" is inside bounds of split
+ * Checks that bounds of new partition "spec" are inside bounds of split
* partition (with Oid splitPartOid). If first=true (this means that "spec" is
* the first of new partitions) then lower bound of "spec" should be equal (or
* greater than or equal in case defaultPart=true) to lower bound of split
@@ -5274,7 +5274,7 @@ check_partition_bounds_for_split_range(Relation parent,
*
* (function for BY LIST partitioning)
*
- * Checks that bounds of new partition is inside bounds of split partition
+ * Checks that bounds of new partition are inside bounds of split partition
* (with Oid splitPartOid).
*
* parent: partitioned table
@@ -5445,8 +5445,8 @@ check_parent_values_in_new_partitions(Relation parent,
Assert(key->strategy == PARTITION_STRATEGY_LIST);
/*
- * Special processing for NULL value. Search NULL-value if it contains
- * split partition (partOid).
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
*/
if (partition_bound_accepts_nulls(boundinfo) &&
partdesc->oids[boundinfo->null_index] == partOid)
@@ -5461,7 +5461,7 @@ check_parent_values_in_new_partitions(Relation parent,
/*
* Search all values of split partition with partOid in PartitionDesc of
- * partitionde table.
+ * partitioned table.
*/
for (i = 0; i < boundinfo->ndatums; i++)
{
@@ -5498,7 +5498,7 @@ check_parent_values_in_new_partitions(Relation parent,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions not have value %s but split partition has",
+ errmsg("new partitions do not have value %s but split partition does",
searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
}
}
@@ -5645,7 +5645,7 @@ check_partitions_for_split(Relation parent,
{
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ errmsg("all partitions in the list should be DEFAULT because split partition is DEFAULT")),
parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
}
else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
@@ -5714,7 +5714,7 @@ check_partitions_for_split(Relation parent,
if (equal(sps->name, sps2->name))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" already used", sps2->name->relname)),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
parser_errposition(pstate, sps2->name->location));
}
}
@@ -5805,14 +5805,14 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * Lower bound of first partition is a lower bound of merged
+ * Lower bound of first partition is the 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
+ * Upper bound of last partition is the upper bound of merged
* partition.
*/
spec->upperdatums =
diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec
index ec48732c58..dc2b9d3445 100644
--- a/src/test/isolation/specs/partition-merge.spec
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -38,7 +38,7 @@ 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
+# s2 is trying to update inserted row and waits until s1 finishes
# MERGE operation.
permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 23fe99ba28..94b3c59cac 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -20,19 +20,19 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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
+-- ERROR: partition with name "sales_feb2022" is 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
+ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not an ordinary table
--- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
@@ -52,7 +52,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -162,7 +162,7 @@ SELECT * FROM sales_others;
14 | Smith | 510 | 05-04-2022
(1 row)
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
@@ -704,7 +704,7 @@ SELECT * FROM sales_all;
13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3d22083e41..46f02013be 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -43,7 +43,7 @@ ERROR: empty range bound specified for partition "sales_mar2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
^
DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
ERROR: list of new partitions should contain at least two items
@@ -55,21 +55,21 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" already used
+ERROR: name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" already used
+ERROR: name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -96,7 +96,7 @@ LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -191,7 +191,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -394,7 +394,7 @@ LINE 1: SELECT * FROM sales_jan_feb2022;
^
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -441,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
@@ -503,7 +503,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -537,7 +537,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -547,15 +547,15 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
^
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
-ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
^
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -564,7 +564,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -616,7 +616,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
@@ -629,7 +629,7 @@ INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -770,11 +770,11 @@ DROP TABLE salesmans CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
@@ -793,7 +793,7 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
salesman_name | |
(2 rows)
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -1036,7 +1036,7 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -1063,8 +1063,8 @@ LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -1075,18 +1075,18 @@ CREATE TABLE sales_list
PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions not have value NULL but split partition has
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value 'Kyiv' but split partition does
DROP TABLE sales_list;
--
-- Test: BY LIST partitioning, SPLIT PARTITION with data
@@ -1174,7 +1174,7 @@ SELECT * FROM sales_central;
13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 98738e165b..af5c2dab6e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -26,14 +26,14 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- ERROR: partition with name "sales_feb2022" already used
+-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not an ordinary table
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
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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;
@@ -48,7 +48,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -96,7 +96,7 @@ SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb_mar_apr2022;
SELECT * FROM sales_others;
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -415,7 +415,7 @@ SELECT * FROM sales_list;
SELECT * FROM sales_nord;
SELECT * FROM sales_all;
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 5dc2fc39cd..576f9f0f63 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -42,7 +42,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
@@ -52,14 +52,14 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -77,7 +77,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -133,7 +133,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -219,7 +219,7 @@ SELECT * FROM sales_jan_feb2022;
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -250,7 +250,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
@@ -270,7 +270,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -299,7 +299,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -307,13 +307,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -325,7 +325,7 @@ DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -361,7 +361,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
@@ -372,7 +372,7 @@ DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -470,12 +470,12 @@ DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
@@ -484,7 +484,7 @@ INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
@@ -609,7 +609,7 @@ CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Pete
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -631,8 +631,8 @@ DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -645,13 +645,13 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
@@ -703,7 +703,7 @@ SELECT * FROM sales_east;
SELECT * FROM sales_nord;
SELECT * FROM sales_central;
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
--
2.40.1.windows.1
Hi Dmitry,
12.04.2024 16:04, Dmitry Koval wrote:
Hi!
Attached is a patch with corrections based on comments in previous letters (I think these corrections are not final).
I'll be very grateful for feedbacks and bug reports.11.04.2024 20:00, Alexander Lakhin wrote:
may be an attempt to merge into implicit
pg_temp should fail just like CREATE TABLE ... PARTITION OF ... does?Corrected. Result is:
Thank you!
Still now we're able to create a partition in the pg_temp schema
explicitly. Please try:
ALTER TABLE t
MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
in the scenario [1]/messages/by-id/fdaa003e-919c-cbc9-4f0c-e4546e96bd65@gmail.com and you'll get the same empty table.
[1]: /messages/by-id/fdaa003e-919c-cbc9-4f0c-e4546e96bd65@gmail.com
Best regards,
Alexander
Thanks, Alexander!
Still now we're able to create a partition in the pg_temp schema
explicitly.
Attached patches with fix.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v5-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchtext/plain; charset=UTF-8; name=v5-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From 2b68bbdb068e881e8ca6e34dec735f7ce656374f Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v5 1/2] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 32 +++--
src/backend/parser/parse_utilcmd.c | 36 ++++-
src/test/regress/expected/partition_merge.out | 124 +++++++++++++++++-
src/test/regress/expected/partition_split.out | 29 ++++
src/test/regress/sql/partition_merge.sql | 101 +++++++++++++-
src/test/regress/sql/partition_split.sql | 23 ++++
6 files changed, 324 insertions(+), 21 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8a98a0af48..b59e1dda03 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21145,17 +21145,19 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ newPartName->relpersistence = rel->rd_rel->relpersistence;
+
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
createStmt->tableElts = NIL;
@@ -21291,7 +21293,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
+ createPartitionTable(rel, sps->name, parentName, context);
/* Open the new partition and acquire exclusive lock on it. */
newPartRel = table_openrv(sps->name, AccessExclusiveLock);
@@ -21488,10 +21490,10 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
/* 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);
+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
- createPartitionTable(mergePartName,
+ createPartitionTable(rel,
+ mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21507,12 +21509,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21542,7 +21538,19 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
RenameRelationInternal(RelationGetRelid(newPartRel),
cmd->name->relname, false, false);
+ /*
+ * Bump the command counter to make the tuple of renamed partition
+ * visible for attach partition operation.
+ */
+ CommandCounterIncrement();
}
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba069905..997f9bedf2 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3415,13 +3415,12 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
table_close(rel, NoLock);
}
-
/*
- * checkPartition
+ * checkOldPartition
* Check that partRelOid is an oid of partition of the parent table rel
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkOldPartition(Relation rel, Oid partRelOid)
{
Relation partRel;
@@ -3430,7 +3429,7 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not an ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
@@ -3449,6 +3448,26 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * checkNewPartition
+ * Check that the new partition has the correct namespace.
+ */
+static void
+checkNewPartition(Relation rel, RangeVar *partName)
+{
+ Oid nspid;
+
+ nspid = RangeVarGetCreationNamespace(partName);
+
+ /* If the parent table is permanent, so must be all of its partitions. */
+ if (rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ isTempOrTempToastNamespace(nspid))
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(rel))));
+}
+
/*
* transformPartitionCmdForSplit
* Analyze the ALTER TABLLE ... SPLIT PARTITION command
@@ -3477,11 +3496,13 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
transformPartitionCmd(cxt, sps->bound);
/* Assign transformed value of the partition bound. */
sps->bound = cxt->partbound;
+ /* Check that the new partition has the correct namespace. */
+ checkNewPartition(parent, sps->name);
}
splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
- checkPartition(parent, splitPartOid);
+ checkOldPartition(parent, splitPartOid);
/* Then we should check partitions with transformed bounds. */
check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
@@ -3521,6 +3542,9 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("partition of hash-partitioned table cannot be merged")));
+ /* Check that the new partition has the correct namespace. */
+ checkNewPartition(parent, partcmd->name);
+
/* Is current partition a DEFAULT partition? */
defaultPartOid = get_default_oid_from_partdesc(
RelationGetPartitionDesc(parent, true));
@@ -3546,7 +3570,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (partOid == defaultPartOid)
isDefaultPart = true;
- checkPartition(parent, partOid);
+ checkOldPartition(parent, partOid);
partOids = lappend_oid(partOids, partOid);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf3..2d6a8474e7 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not an ordinary table
-- 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;
@@ -746,4 +746,124 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+ indexname
+--------------
+ tp_1_2_i_idx
+(1 row)
+
+DROP TABLE t;
+--
+-- 1. Try creating a partition of the permanent relation in a temporary schema.
+-- 2. Try to create a partition in the pg_temp schema explicitly.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, public;
+-- 1.
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = public, pg_temp;
+-- 2.
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+RESET search_path;
+--
+-- Try creating a partition of the temporary relation in a permanent schema.
+--
+SET search_path = pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = public, pg_temp;
+-- There is no problem with creating a temporary partition in a permanent schema.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition tp_0_2 should be temporary (t).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+SET search_path = pg_temp, pg_temp;
+DROP TABLE t;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d09969..3d22083e41 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365..8a3c3f4a4b 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
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)
@@ -444,5 +444,104 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+
+DROP TABLE t;
+
+--
+-- 1. Try creating a partition of the permanent relation in a temporary schema.
+-- 2. Try to create a partition in the pg_temp schema explicitly.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, public;
+
+-- 1.
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = public, pg_temp;
+
+-- 2.
+-- ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+
+DROP TABLE t;
+RESET search_path;
+
+--
+-- Try creating a partition of the temporary relation in a permanent schema.
+--
+SET search_path = pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = public, pg_temp;
+
+-- There is no problem with creating a temporary partition in a permanent schema.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition tp_0_2 should be temporary (t).
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, pg_temp;
+
+DROP TABLE t;
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1..5dc2fc39cd 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.40.1.windows.1
v5-0002-Fixes-for-english-text.patchtext/plain; charset=UTF-8; name=v5-0002-Fixes-for-english-text.patchDownload
From c4dccd827e769bd0ba03c65634235a8537bf30f4 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 19:55:18 +0300
Subject: [PATCH v5 2/2] Fixes for english text
---
doc/src/sgml/ddl.sgml | 2 +-
doc/src/sgml/ref/alter_table.sgml | 6 +-
src/backend/commands/tablecmds.c | 16 ++---
src/backend/parser/parse_utilcmd.c | 6 +-
src/backend/partitioning/partbounds.c | 30 +++++-----
src/test/isolation/specs/partition-merge.spec | 2 +-
src/test/regress/expected/partition_merge.out | 14 ++---
src/test/regress/expected/partition_split.out | 58 +++++++++----------
src/test/regress/sql/partition_merge.sql | 12 ++--
src/test/regress/sql/partition_split.sql | 48 +++++++--------
10 files changed, 97 insertions(+), 97 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 00f44f56fa..026bfff70f 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4387,7 +4387,7 @@ ALTER INDEX measurement_city_id_logdate_key
a single partition using the
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
- administrators to combine partitions that are no longer needed as
+ users to combine partitions that are no longer needed as
separate entities. It's important to note that this operation is not
supported for hash-partitioned tables and acquires an
<literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8f5bf185dd..fe36ff82e5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1175,7 +1175,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables is necessary that the ranges
+ For range-partitioned tables it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
be merged into one range without spaces and overlaps (otherwise an error
@@ -1185,10 +1185,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For list-partitioned tables the values lists of all partitions
+ For list-partitioned tables the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form a list of values of partition
+ combined and form the list of values of partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b59e1dda03..f58ff43699 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20888,7 +20888,7 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
/*
- * Struct with context of new partition for insert rows from splited partition
+ * Struct with context of new partition for inserting rows from split partition
*/
typedef struct SplitPartitionContext
{
@@ -20945,7 +20945,7 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
*
* New partitions description:
* partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relation's.
+ * newPartRels: list of Relations.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -21030,7 +21030,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* Map computing for moving attributes of split partition to new partition
- * (for first new partition but other new partitions can use the same
+ * (for first new partition, but other new partitions can use the same
* map).
*/
pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
@@ -21085,7 +21085,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
}
else
@@ -21245,7 +21245,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
/*
- * This would fail later on anyway, if the relation already exists.
+ * This would fail later on anyway if the relation already exists.
* But by catching it here we can emit a nicer error message.
*/
existing_relid = get_relname_relid(relname, namespaceId);
@@ -21312,7 +21312,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel = (Relation) lfirst(listptr2);
- /* wqueue = NULL: verification for each cloned constraint is not need. */
+ /* wqueue = NULL: verification for each cloned constraint is not needed. */
attachPartitionTable(NULL, rel, newPartRel, sps->bound);
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
@@ -21386,7 +21386,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
if (tuple_map)
{
- /* Need to use map for copy attributes. */
+ /* Need to use map to copy attributes. */
insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
}
else
@@ -21488,7 +21488,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
if (isSameName)
{
- /* Create partition table with generated temparary name. */
+ /* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 997f9bedf2..75362df50a 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3513,7 +3513,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
* transformPartitionCmdForMerge
* Analyze the ALTER TABLLE ... MERGE PARTITIONS command
*
- * Does simple checks for merged partitions. Calculates bound of result
+ * Does simple checks for merged partitions. Calculates bound of resulting
* partition.
*/
static void
@@ -3561,7 +3561,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
if (equal(name, name2))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("partition with name \"%s\" already used", name->relname)),
+ errmsg("partition with name \"%s\" is already used", name->relname)),
parser_errposition(cxt->pstate, name2->location));
}
@@ -3575,7 +3575,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partOids = lappend_oid(partOids, partOid);
}
- /* Allocate bound of result partition. */
+ /* Allocate bound of resulting partition. */
Assert(partcmd->bound == NULL);
partcmd->bound = makeNode(PartitionBoundSpec);
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index c0c49b0a0b..f89bdb3c86 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,7 +3214,7 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
+ * Point to problematic key in the list of lower datums;
* if we have equality, point to the first one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
@@ -4986,10 +4986,10 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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 equal except case
+ * second_bound. These bounds should be equal except when
* "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
+ * second_bound because space between these bounds will be included in
* DEFAULT partition.
*
* parent: partitioned table
@@ -4998,7 +4998,7 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* 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
+ * pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
@@ -5020,7 +5020,7 @@ check_two_partitions_bounds_range(Relation parent,
second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true);
/*
- * lower1=false (the second to last argument) for correct comparison lower
+ * lower1=false (the second to last argument) for correct comparison of lower
* and upper bounds.
*/
cmpval = partition_rbound_cmp(key->partnatts,
@@ -5140,7 +5140,7 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
*
* (function for BY RANGE partitioning)
*
- * Checks that bounds of new partition "spec" is inside bounds of split
+ * Checks that bounds of new partition "spec" are inside bounds of split
* partition (with Oid splitPartOid). If first=true (this means that "spec" is
* the first of new partitions) then lower bound of "spec" should be equal (or
* greater than or equal in case defaultPart=true) to lower bound of split
@@ -5274,7 +5274,7 @@ check_partition_bounds_for_split_range(Relation parent,
*
* (function for BY LIST partitioning)
*
- * Checks that bounds of new partition is inside bounds of split partition
+ * Checks that bounds of new partition are inside bounds of split partition
* (with Oid splitPartOid).
*
* parent: partitioned table
@@ -5445,8 +5445,8 @@ check_parent_values_in_new_partitions(Relation parent,
Assert(key->strategy == PARTITION_STRATEGY_LIST);
/*
- * Special processing for NULL value. Search NULL-value if it contains
- * split partition (partOid).
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
*/
if (partition_bound_accepts_nulls(boundinfo) &&
partdesc->oids[boundinfo->null_index] == partOid)
@@ -5461,7 +5461,7 @@ check_parent_values_in_new_partitions(Relation parent,
/*
* Search all values of split partition with partOid in PartitionDesc of
- * partitionde table.
+ * partitioned table.
*/
for (i = 0; i < boundinfo->ndatums; i++)
{
@@ -5498,7 +5498,7 @@ check_parent_values_in_new_partitions(Relation parent,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions not have value %s but split partition has",
+ errmsg("new partitions do not have value %s but split partition does",
searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
}
}
@@ -5645,7 +5645,7 @@ check_partitions_for_split(Relation parent,
{
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("any partition in the list should be DEFAULT because split partition is DEFAULT")),
+ errmsg("all partitions in the list should be DEFAULT because split partition is DEFAULT")),
parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
}
else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
@@ -5714,7 +5714,7 @@ check_partitions_for_split(Relation parent,
if (equal(sps->name, sps2->name))
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" already used", sps2->name->relname)),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
parser_errposition(pstate, sps2->name->location));
}
}
@@ -5805,14 +5805,14 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * Lower bound of first partition is a lower bound of merged
+ * Lower bound of first partition is the 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
+ * Upper bound of last partition is the upper bound of merged
* partition.
*/
spec->upperdatums =
diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec
index ec48732c58..dc2b9d3445 100644
--- a/src/test/isolation/specs/partition-merge.spec
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -38,7 +38,7 @@ 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
+# s2 is trying to update inserted row and waits until s1 finishes
# MERGE operation.
permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2d6a8474e7..cb50229b87 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -20,19 +20,19 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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
+-- ERROR: partition with name "sales_feb2022" is 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
+ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not an ordinary table
--- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
@@ -52,7 +52,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -162,7 +162,7 @@ SELECT * FROM sales_others;
14 | Smith | 510 | 05-04-2022
(1 row)
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
@@ -704,7 +704,7 @@ SELECT * FROM sales_all;
13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
salesman_id | salesman_name | sales_state | sales_amount | sales_date
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3d22083e41..46f02013be 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -43,7 +43,7 @@ ERROR: empty range bound specified for partition "sales_mar2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
^
DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
ERROR: list of new partitions should contain at least two items
@@ -55,21 +55,21 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" already used
+ERROR: name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" already used
+ERROR: name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -96,7 +96,7 @@ LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -191,7 +191,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -394,7 +394,7 @@ LINE 1: SELECT * FROM sales_jan_feb2022;
^
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -441,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
@@ -503,7 +503,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -537,7 +537,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -547,15 +547,15 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
^
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
-ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
^
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -564,7 +564,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -616,7 +616,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
@@ -629,7 +629,7 @@ INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -770,11 +770,11 @@ DROP TABLE salesmans CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
@@ -793,7 +793,7 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
salesman_name | |
(2 rows)
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
@@ -1036,7 +1036,7 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -1063,8 +1063,8 @@ LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -1075,18 +1075,18 @@ CREATE TABLE sales_list
PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions not have value NULL but split partition has
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions not have value 'Kyiv' but split partition has
+ERROR: new partitions do not have value 'Kyiv' but split partition does
DROP TABLE sales_list;
--
-- Test: BY LIST partitioning, SPLIT PARTITION with data
@@ -1174,7 +1174,7 @@ SELECT * FROM sales_central;
13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 8a3c3f4a4b..677d404647 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -26,14 +26,14 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- ERROR: partition with name "sales_feb2022" already used
+-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not an ordinary table
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
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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
+-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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;
@@ -48,7 +48,7 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
DROP TABLE sales_range;
--
--- Add rows into partitioned table then merge partitions
+-- 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');
@@ -96,7 +96,7 @@ SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb_mar_apr2022;
SELECT * FROM sales_others;
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -415,7 +415,7 @@ SELECT * FROM sales_list;
SELECT * FROM sales_nord;
SELECT * FROM sales_all;
--- Use indexscan for test indexes after merge partitions
+-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 5dc2fc39cd..576f9f0f63 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -42,7 +42,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
---ERROR: list of split partitions should contains at least two items
+--ERROR: list of split partitions should contain at least two items
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
@@ -52,14 +52,14 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb_mar_apr2022" already used
+-- ERROR: name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
--- ERROR: name "sales_feb2022" already used
+-- ERROR: name "sales_feb2022" is already used
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -77,7 +77,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
--- ERROR: lower bound of partition "sales_mar2022" is not equals to upper bound of previous partition
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
@@ -86,7 +86,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
--- ERROR: lower bound of partition "sales_feb2022" is not equals to lower bound of split partition
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
@@ -133,7 +133,7 @@ SELECT * FROM sales_others;
DROP TABLE sales_range CASCADE;
--
--- Add split partition then add rows into partitioned table
+-- Add split partition, then add rows into partitioned table
--
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');
@@ -219,7 +219,7 @@ SELECT * FROM sales_jan_feb2022;
DROP TABLE sales_date CASCADE;
--
--- Test: split DEFAULT partition; using a index on partition key; check index after split
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
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');
@@ -250,7 +250,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
PARTITION sales_others DEFAULT);
--- Use indexscan for test indexes
+-- Use indexscan for testing indexes
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
@@ -270,7 +270,7 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'part
DROP TABLE sales_range CASCADE;
--
--- Test: some cases for split DEFAULT partition (different bounds)
+-- Test: some cases for splitting DEFAULT partition (different bounds)
--
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -299,7 +299,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- sales_error intersects with sales_dec2022 (exact the same bounds)
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
@@ -307,13 +307,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
--- ERROR: any partition in the list should be DEFAULT because split partition is DEFAULT
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
--- no error: bounds of sales_noerror between sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
@@ -325,7 +325,7 @@ DROP TABLE sales_range;
CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
--- no error: bounds of sales_noerror equals to lower and upper bounds of sales_dec2022 and sales_feb2022
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
@@ -361,7 +361,7 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
--- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_salesman_id_check"
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
@@ -372,7 +372,7 @@ DROP TABLE sales_range CASCADE;
DROP TABLE salesmans CASCADE;
--
--- Test: split partition on partitioned table in case exists FOREIGN KEY reference from another table
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
@@ -470,12 +470,12 @@ DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
--- If split partition column is identity-column, columns of new partitions are identity-columns too.
+-- If split partition column is identity column, columns of new partitions are identity columns too.
--
CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
--- Create new partition with identity-column:
+-- Create new partition with identity column:
CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
@@ -484,7 +484,7 @@ INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
--- Split partition has identity-column:
+-- Split partition has identity column:
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
@@ -609,7 +609,7 @@ CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Pete
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
--- ERROR: partition "sales_east" would overlap partition "sales_nord"
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
@@ -631,8 +631,8 @@ DROP TABLE sales_list;
--
-- Test: two specific errors for BY LIST partitioning:
--- * new partitions not has NULL value that split partition has.
--- * new partitions not has a value that split partition has.
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
(salesman_id INT,
@@ -645,13 +645,13 @@ PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
--- ERROR: new partitions not have value NULL but split partition has
+-- ERROR: new partitions do not have value NULL but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
--- ERROR: new partitions not have value 'Kyiv' but split partition has
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
@@ -703,7 +703,7 @@ SELECT * FROM sales_east;
SELECT * FROM sales_nord;
SELECT * FROM sales_central;
--- Use indexscan for test indexes after split partition
+-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
--
2.40.1.windows.1
Hi, Dmitry!
On Fri, Apr 12, 2024 at 10:59 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thanks, Alexander!
Still now we're able to create a partition in the pg_temp schema
explicitly.Attached patches with fix.
Please, find a my version of this fix attached. I think we need to
check relpersistence in a similar way ATTACH PARTITION or CREATE TABLE
... PARTITION OF do. I'm going to polish this a little bit more.
------
Regards,
Alexander Korotkov
Attachments:
v6-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchapplication/octet-stream; name=v6-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patchDownload
From abfbd47c4d5ae6cc6ff538688fe2b85601912e18 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Wed, 10 Apr 2024 18:54:05 +0300
Subject: [PATCH v6] Fix for SPLIT/MERGE partitions of temporary table
---
src/backend/commands/tablecmds.c | 84 +++++++++++++------
src/backend/parser/parse_utilcmd.c | 2 +-
src/test/regress/expected/partition_merge.out | 75 ++++++++++++++++-
src/test/regress/expected/partition_split.out | 29 +++++++
src/test/regress/sql/partition_merge.sql | 69 ++++++++++++++-
src/test/regress/sql/partition_split.sql | 23 +++++
6 files changed, 253 insertions(+), 29 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 000212f24c4..d38eb51002f 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21124,16 +21124,24 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+static Relation
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !rel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
@@ -21172,6 +21180,35 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL,
None_Receiver,
NULL);
+
+ /*
+ * Open the new partition and acquire exclusive lock on it. This will
+ * stop all the operations with partitioned table. This might seem
+ * excessive, but this is the way we make sure nobody is planning queries
+ * involving merging partitions.
+ */
+ newRel = table_openrv(newPartName, AccessExclusiveLock);
+
+ /*
+ * If the parent is permanent, so must be all of its partitions. Note
+ * that inheritance allows that case.
+ */
+ if (rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(rel))));
+
+ /* Permanent rels cannot inherit from temporary ones */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(rel))));
+
+ return newRel;
}
/*
@@ -21270,11 +21307,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
+ newPartRel = createPartitionTable(rel, sps->name, parentName, context);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21466,28 +21499,16 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
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. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ newPartRel = createPartitionTable(rel,
+ mergePartName,
+ makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1),
+ context);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21517,7 +21538,20 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Rename partition. */
RenameRelationInternal(RelationGetRelid(newPartRel),
cmd->name->relname, false, false);
+
+ /*
+ * Bump the command counter to make the tuple of renamed partition
+ * visible for attach partition operation.
+ */
+ CommandCounterIncrement();
}
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ceba0699050..a3bbcc99c02 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3430,7 +3430,7 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not an ordinary table",
RelationGetRelationName(partRel))));
if (!partRel->rd_rel->relispartition)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 60eacf6bf39..b1d0b50b0b4 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -25,9 +25,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_fe
ERROR: partition with name "sales_feb2022" already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
^
--- ERROR: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-ERROR: "sales_apr2022" is not a table
+ERROR: "sales_apr2022" is not an ordinary table
-- 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;
@@ -746,4 +746,75 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+ indexname
+--------------
+ tp_1_2_i_idx
+(1 row)
+
+DROP TABLE t;
+--
+-- Try creating a partition in the temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET search_path = pg_temp, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+DROP TAble tp_0_2;
+ERROR: table "tp_0_2" does not exist
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET search_path = public, pg_temp;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 26a0d099696..46cd82ce191 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9afed70365f..2d55e0f5a38 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -28,7 +28,7 @@ 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: "sales_apr2022" is not a table
+-- ERROR: "sales_apr2022" is not an ordinary table
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)
@@ -444,5 +444,72 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
+
+DROP TABLE t;
+
+--
+-- Try creating a partition in the temporary schema.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET search_path = pg_temp, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+DROP TABLE t;
+DROP TAble tp_0_2;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET search_path = public, pg_temp;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 625b01ddd1f..5dc2fc39cd5 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
On Sat, Apr 13, 2024 at 6:05 AM Alexander Korotkov <aekorotkov@gmail.com> wrote:
Please, find a my version of this fix attached. I think we need to
check relpersistence in a similar way ATTACH PARTITION or CREATE TABLE
... PARTITION OF do. I'm going to polish this a little bit more.
+ errmsg("\"%s\" is not an ordinary table",
This is not a phrasing that we use in any other error message. We
always just say "is not a table".
+ * Open the new partition and acquire exclusive lock on it. This will
A minor nitpick is that this should probably say access exclusive
rather than exclusive. But the bigger thing that confuses me here is
that if we just created the partition, surely we must *already* hold
AccessExclusiveLoc on it. No?
--
Robert Haas
EDB: http://www.enterprisedb.com
Hello Robert,
15.04.2024 17:30, Robert Haas wrote:
On Sat, Apr 13, 2024 at 6:05 AM Alexander Korotkov <aekorotkov@gmail.com> wrote:
Please, find a my version of this fix attached. I think we need to
check relpersistence in a similar way ATTACH PARTITION or CREATE TABLE
... PARTITION OF do. I'm going to polish this a little bit more.+ errmsg("\"%s\" is not an ordinary table",
This is not a phrasing that we use in any other error message. We
always just say "is not a table".
Initially I was confused by that message, because of:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE FOREIGN TABLE ftp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1)
SERVER loopback OPTIONS (table_name 'lt_0_1');
CREATE FOREIGN TABLE ftp_1_2 PARTITION OF t
FOR VALUES FROM (1) TO (2)
SERVER loopback OPTIONS (table_name 'lt_1_2');
ALTER TABLE t MERGE PARTITIONS (ftp_0_1, ftp_1_2) INTO ftp_0_2;
ERROR: "ftp_0_1" is not a table
(Isn't a foreign table a table?)
And also:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1);
CREATE TABLE t2 (i int) PARTITION BY RANGE (i);
ALTER TABLE t MERGE PARTITIONS (tp_0_1, t2) INTO tpn;
ERROR: "t2" is not a table
(Isn't a partitioned table a table?)
And in fact, an ordinary table is not suitable for MERGE anyway:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1);
CREATE TABLE t2 (i int);
ALTER TABLE t MERGE PARTITIONS (tp_0_1, t2) INTO tpn;
ERROR: "t2" is not a partition
So I don't think that "an ordinary table" is a good (unambiguous) term
either.
Best regards,
Alexander
Hi!
Please, find a my version of this fix attached.
Is it possible to make a small addition to the file v6-0001 ... .patch
(see attachment)?
Most important:
1) Line 19:
+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
(temporary table should use the same schema as the partition);
2) Lines 116-123:
+RESET search_path;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+
+SET search_path = pg_temp, public;
(Alexandr Lakhin's test for using of pg_temp schema explicitly).
The rest of the changes in v6_afterfix.diff are not very important and
can be ignored.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v6_afterfix.difftext/plain; charset=UTF-8; name=v6_afterfix.diffDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index c6ce7b94d9..bce5e39b64 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21130,6 +21130,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * Function locks created relation in AccessExclusiveLock mode and returns it.
*/
static Relation
createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
@@ -21500,8 +21501,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
/* 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);
+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
newPartRel = createPartitionTable(rel,
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index b1d0b50b0b..0a4022f714 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -793,23 +793,58 @@ SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
DROP TABLE t;
--
--- Try creating a partition in the temporary schema.
+-- Try mixing permanent and temporary partitions.
--
SET search_path = public, pg_temp;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
SET search_path = pg_temp, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ERROR: cannot create a temporary relation as partition of permanent relation "t"
+RESET search_path;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
DROP TABLE t;
-DROP TAble tp_0_2;
-ERROR: table "tp_0_2" does not exist
+SET search_path = pg_temp, public;
BEGIN;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
SET search_path = public, pg_temp;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 2d55e0f5a3..56adcf4bfc 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -484,25 +484,43 @@ SELECT indexname FROM pg_indexes WHERE tablename = 'tp_1_2';
DROP TABLE t;
--
--- Try creating a partition in the temporary schema.
+-- Try mixing permanent and temporary partitions.
--
SET search_path = public, pg_temp;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
SET search_path = pg_temp, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+RESET search_path;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
DROP TABLE t;
-DROP TAble tp_0_2;
+
+SET search_path = pg_temp, public;
BEGIN;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
SET search_path = public, pg_temp;
-- Can't merge temporary partitions into a persistent partition
On Mon, Apr 15, 2024 at 11:00 AM Alexander Lakhin <exclusion@gmail.com> wrote:
Initially I was confused by that message, because of:
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE FOREIGN TABLE ftp_0_1 PARTITION OF t
FOR VALUES FROM (0) TO (1)
SERVER loopback OPTIONS (table_name 'lt_0_1');
CREATE FOREIGN TABLE ftp_1_2 PARTITION OF t
FOR VALUES FROM (1) TO (2)
SERVER loopback OPTIONS (table_name 'lt_1_2');
ALTER TABLE t MERGE PARTITIONS (ftp_0_1, ftp_1_2) INTO ftp_0_2;
ERROR: "ftp_0_1" is not a table
(Isn't a foreign table a table?)
I agree that this can be confusing, but a patch that is about adding
SPLIT and MERGE PARTITION operations cannot decide to also invent a
new error message phraseology and use it only in one place. We need to
maintain consistency across the whole code base.
--
Robert Haas
EDB: http://www.enterprisedb.com
Hi, Dmitry!
On Mon, Apr 15, 2024 at 6:26 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Please, find a my version of this fix attached.
Is it possible to make a small addition to the file v6-0001 ... .patch
(see attachment)?Most important:
1) Line 19:+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
(temporary table should use the same schema as the partition);
2) Lines 116-123:
+RESET search_path; + +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; + +SET search_path = pg_temp, public;(Alexandr Lakhin's test for using of pg_temp schema explicitly).
The rest of the changes in v6_afterfix.diff are not very important and
can be ignored.
Thank you. I've integrated your changes.
The revised patchset is attached.
1) I've split the fix for the CommandCounterIncrement() issue and the
fix for relation persistence issue into a separate patch.
2) I've validated that the lock on the new partition is held in
createPartitionTable() after ProcessUtility() as pointed out by
Robert. So, no need to place the lock again.
3) Added fix for problematic error message as a separate patch [1].
4) Added rename "salemans" => "salesmen" for tests as a separate patch.
I think these fixes are reaching committable shape, but I'd like
someone to check it before I push.
Links.
1. /messages/by-id/20240408.152402.1485994009160660141.horikyota.ntt@gmail.com
------
Regards,
Alexander Korotkov
Attachments:
v6-0002-Verify-persistence-of-new-partitions-during-MERGE.patchapplication/octet-stream; name=v6-0002-Verify-persistence-of-new-partitions-during-MERGE.patchDownload
From 57d38e20b28ade963bd33273c2fc2d8c032f549c Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:41:09 +0300
Subject: [PATCH v6 2/4] Verify persistence of new partitions during
MERGE/SPLIT operations
The createPartitionTable() function is responsible for creating new partitions
for ALTER TABLE ... MERGE PARTITIONS, and ALTER TABLE ... SPLIT PARTITION
commands. It emulates the behavious of CREATE TABLE ... (LIKE ...), but
lacks of check for the result relation persistence. This commit adds
corresponsing check similarly to what we have for CREATE TABLE ...
PARTITION OF command.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/dbc8b96c-3cf0-d1ee-860d-0e491da20485%40gmail.com
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
src/backend/commands/tablecmds.c | 67 +++++++++-----
src/test/regress/expected/partition_merge.out | 89 +++++++++++++++++++
src/test/regress/expected/partition_split.out | 29 ++++++
src/test/regress/sql/partition_merge.sql | 68 ++++++++++++++
src/test/regress/sql/partition_split.sql | 23 +++++
5 files changed, 255 insertions(+), 21 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 87427ad7d2e..d894d5a73fd 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21133,16 +21133,25 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRelName)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRelName>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+static Relation
+createPartitionTable(Relation rel, RangeVar *newPartName, RangeVar *modelRelName,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !rel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
@@ -21181,6 +21190,33 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL,
None_Receiver,
NULL);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * If the parent is permanent, so must be all of its partitions. Note
+ * that inheritance allows that case.
+ */
+ if (rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(rel))));
+
+ /* Permanent rels cannot inherit from temporary ones */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(rel))));
+
+ return newRel;
}
/*
@@ -21279,11 +21315,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
+ newPartRel = createPartitionTable(rel, sps->name, parentName, context);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21475,21 +21507,14 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
/* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- tmpRelName, -1);
+ mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
}
- createPartitionTable(mergePartName,
- makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1),
- context);
- /*
- * Open the new partition and acquire exclusive lock on it. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ newPartRel = createPartitionTable(rel,
+ mergePartName,
+ makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel), -1),
+ context);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 3593720731c..748c8c7a89b 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,6 +746,36 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
@@ -764,4 +794,63 @@ WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
DROP TABLE t;
--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+RESET search_path;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = public, pg_temp;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 419d169f036..660361cd20e 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 940e6b5a9e5..6faac959a7c 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,6 +444,28 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
@@ -462,5 +484,51 @@ WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+RESET search_path;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = public, pg_temp;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b63532ee562..576f9f0f63c 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
v6-0004-Grammar-fix-for-tests-of-partition-MERGE-SPLIT-op.patchapplication/octet-stream; name=v6-0004-Grammar-fix-for-tests-of-partition-MERGE-SPLIT-op.patchDownload
From 5032cdf6dd9905fe16b15890e822bef88c2f6142 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 13:27:11 +0300
Subject: [PATCH v6 4/4] Grammar fix for tests of partition MERGE/SPLIT
operations
Replace "salesmans" with "salesmen".
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/fdaa003e-919c-cbc9-4f0c-e4546e96bd65%40gmail.com
---
src/test/regress/expected/partition_merge.out | 96 +++----
src/test/regress/expected/partition_split.out | 238 +++++++++---------
src/test/regress/sql/partition_merge.sql | 84 +++----
src/test/regress/sql/partition_split.sql | 186 +++++++-------
4 files changed, 302 insertions(+), 302 deletions(-)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 748c8c7a89b..b5744ed4986 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -349,50 +349,50 @@ 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 TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_20 PARTITION OF salesmen FOR VALUES FROM (10) TO (20);
+CREATE TABLE salesmen20_30 PARTITION OF salesmen FOR VALUES FROM (20) TO (30);
+CREATE TABLE salesmen30_40 PARTITION OF salesmen FOR VALUES FROM (30) TO (40);
+INSERT INTO salesmen 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
+CREATE TRIGGER salesmen_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
+CREATE TRIGGER salesmen_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-- 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
+INSERT INTO salesmen VALUES (10, 'May');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salesmen) 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;
+INSERT INTO salesmen10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmen MERGE PARTITIONS (salesmen10_20, salesmen20_30, salesmen30_40) INTO salesmen10_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
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salesmen) 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;
+INSERT INTO salesmen10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
+SELECT * FROM salesmen10_40;
salesman_id | salesman_name
-------------+---------------
10 | May
@@ -401,31 +401,31 @@ SELECT * FROM salesmans10_40;
30 | Ford
(4 rows)
-DROP TABLE salesmans;
+DROP TABLE salesmen;
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 TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen 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;
+CREATE TABLE salesmen10_20(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+CREATE TABLE salesmen20_30(salesman_id INT PRIMARY KEY, d2 INT, salesman_name VARCHAR(30));
+CREATE TABLE salesmen30_40(salesman_id INT PRIMARY KEY, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmen10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salesmen20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salesmen30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salesmen10_20 DROP COLUMN d1;
+ALTER TABLE salesmen20_30 DROP COLUMN d2;
+ALTER TABLE salesmen30_40 DROP COLUMN d3;
+ALTER TABLE salesmen ATTACH PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salesmen ATTACH PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salesmen ATTACH PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (30, 'Ford');
+ALTER TABLE salesmen MERGE PARTITIONS (salesmen10_20, salesmen20_30, salesmen30_40) INTO salesmen10_40;
+select * from salesmen;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
@@ -436,13 +436,13 @@ select * from salesmans;
30 | Ford
(6 rows)
-select * from salesmans01_10;
+select * from salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-select * from salesmans10_40;
+select * from salesmen10_40;
salesman_id | salesman_name
-------------+---------------
19 | Ivanov
@@ -452,7 +452,7 @@ select * from salesmans10_40;
30 | Ford
(5 rows)
-DROP TABLE salesmans;
+DROP TABLE salesmen;
--
-- Test: merge sub-partitions
--
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 660361cd20e..217e9ba54bb 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -84,8 +84,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
- ^
+LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -574,20 +574,20 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmen VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesman_id INT REFERENCES salesmen(salesman_id),
sales_amount INT CHECK (sales_amount > 1),
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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmen(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -596,24 +596,24 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmen(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmen(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+------------------------------------------------------------+--------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesman_id) REFERENCES salesmen(salesman_id) | sales_range_salesman_id_fkey | {1}
(2 rows)
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
@@ -623,23 +623,23 @@ DETAIL: Failing row contains (1, 0, 03-11-2022).
-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+DETAIL: Key (salesman_id)=(-1) is not present in table "salesmen".
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+CREATE TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmen(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_40 PARTITION OF salesmen FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (19, 'Ivanov');
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
+INSERT INTO salesmen VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
INSERT INTO sales VALUES (10, 150, '2022-03-01');
@@ -648,13 +648,13 @@ INSERT INTO sales VALUES (19, 200, '2022-03-04');
INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
+SELECT * FROM salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
+SELECT * FROM salesmen10_40;
salesman_id | salesman_name
-------------+---------------
10 | May
@@ -663,30 +663,30 @@ SELECT * FROM salesmans10_40;
30 | Ford
(4 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
+SELECT * FROM salesmen10_20;
salesman_id | salesman_name
-------------+---------------
10 | May
19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
+SELECT * FROM salesmen20_30;
salesman_id | salesman_name
-------------+---------------
20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
+SELECT * FROM salesmen30_40;
salesman_id | salesman_name
-------------+---------------
30 | Ford
@@ -695,98 +695,98 @@ SELECT * FROM salesmans30_40;
-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+DETAIL: Key (salesman_id)=(40) is not present in table "salesmen".
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_40 PARTITION OF salesmen FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmen 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
+CREATE TRIGGER salesmen_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
+CREATE TRIGGER salesmen_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-- 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
+INSERT INTO salesmen VALUES (10, 'May');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+INSERT INTO salesmen10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (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
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-SELECT * FROM salesmans01_10;
+INSERT INTO salesmen30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salesmen) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
+SELECT * FROM salesmen10_20;
salesman_id | salesman_name
-------------+---------------
10 | May
19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
+SELECT * FROM salesmen20_30;
salesman_id | salesman_name
-------------+---------------
20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
+SELECT * FROM salesmen30_40;
salesman_id | salesman_name
-------------+---------------
30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salesmen(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen1_2 PARTITION OF salesmen FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+CREATE TABLE salesmen2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmen ATTACH PARTITION salesmen2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salesmen (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmen (salesman_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen1_2'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
@@ -794,51 +794,51 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
(2 rows)
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen2_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
+ALTER TABLE salesmen SPLIT PARTITION salesmen2_5 INTO
+ (PARTITION salesmen2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmen3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmen4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salesmen (salesman_name) VALUES ('May');
+INSERT INTO salesmen (salesman_name) VALUES ('Ford');
+SELECT * FROM salesmen1_2;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-SELECT * FROM salesmans2_3;
+SELECT * FROM salesmen2_3;
salesman_id | salesman_name
-------------+---------------
2 | Ivanov
(1 row)
-SELECT * FROM salesmans3_4;
+SELECT * FROM salesmen3_4;
salesman_id | salesman_name
-------------+---------------
3 | May
(1 row)
-SELECT * FROM salesmans4_5;
+SELECT * FROM salesmen4_5;
salesman_id | salesman_name
-------------+---------------
4 | Ford
(1 row)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen1_2'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
@@ -846,74 +846,74 @@ SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND
(2 rows)
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen2_3'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen3_4'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen4_5'::regclass::oid;
attname | attidentity | attgenerated
---------------+-------------+--------------
salesman_id | a |
salesman_name | |
(2 rows)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition 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 TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
+CREATE TABLE salesmen10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+INSERT INTO salesmen10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmen10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salesmen10_40 DROP COLUMN d1;
+ALTER TABLE salesmen10_40 DROP COLUMN d2;
+ALTER TABLE salesmen10_40 DROP COLUMN d3;
+ALTER TABLE salesmen ATTACH PARTITION salesmen10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (30, 'Ford');
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40));
+select * from salesmen01_10;
salesman_id | salesman_name
-------------+---------------
1 | Poirot
(1 row)
-select * from salesmans10_20;
+select * from salesmen10_20;
salesman_id | salesman_name
-------------+---------------
19 | Ivanov
10 | May
(2 rows)
-select * from salesmans20_30;
+select * from salesmen20_30;
salesman_id | salesman_name
-------------+---------------
20 | Smirnoff
(1 row)
-select * from salesmans30_40;
+select * from salesmen30_40;
salesman_id | salesman_name
-------------+---------------
30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split sub-partition
--
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 6faac959a7c..df737e214ee 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -193,14 +193,14 @@ 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 salesmen(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);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_20 PARTITION OF salesmen FOR VALUES FROM (10) TO (20);
+CREATE TABLE salesmen20_30 PARTITION OF salesmen FOR VALUES FROM (20) TO (30);
+CREATE TABLE salesmen30_40 PARTITION OF salesmen FOR VALUES FROM (30) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -209,70 +209,70 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salesmen_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salesmen_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmen VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_20 VALUES (19, 'Ivanov');
+INSERT INTO salesmen10_20 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salesmen MERGE PARTITIONS (salesmen10_20, salesmen20_30, salesmen30_40) INTO salesmen10_40;
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (30, 'Ford');
+INSERT INTO salesmen10_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salesmen01_10;
+SELECT * FROM salesmen10_40;
-DROP TABLE salesmans;
+DROP TABLE salesmen;
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 salesmen(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 salesmen01_10 PARTITION OF salesmen 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));
+CREATE TABLE salesmen10_20(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+CREATE TABLE salesmen20_30(salesman_id INT PRIMARY KEY, d2 INT, salesman_name VARCHAR(30));
+CREATE TABLE salesmen30_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');
+INSERT INTO salesmen10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salesmen20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salesmen30_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 salesmen10_20 DROP COLUMN d1;
+ALTER TABLE salesmen20_30 DROP COLUMN d2;
+ALTER TABLE salesmen30_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);
+ALTER TABLE salesmen ATTACH PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salesmen ATTACH PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salesmen ATTACH PARTITION salesmen30_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');
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (30, 'Ford');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salesmen MERGE PARTITIONS (salesmen10_20, salesmen20_30, salesmen30_40) INTO salesmen10_40;
-select * from salesmans;
-select * from salesmans01_10;
-select * from salesmans10_40;
+select * from salesmen;
+select * from salesmen01_10;
+select * from salesmen10_40;
-DROP TABLE salesmans;
+DROP TABLE salesmen;
--
-- Test: merge sub-partitions
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 576f9f0f63c..12def95d1d5 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -337,11 +337,11 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
+INSERT INTO salesmen VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesman_id INT REFERENCES salesmen(salesman_id),
sales_amount INT CHECK (sales_amount > 1),
sales_date DATE) PARTITION BY RANGE (sales_date);
@@ -369,22 +369,22 @@ INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salesmen(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE sales (salesman_id INT REFERENCES salesmen(salesman_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_40 PARTITION OF salesmen FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (19, 'Ivanov');
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
+INSERT INTO salesmen VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
@@ -395,18 +395,18 @@ INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salesmen01_10;
+SELECT * FROM salesmen10_40;
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salesmen01_10;
+SELECT * FROM salesmen10_20;
+SELECT * FROM salesmen20_30;
+SELECT * FROM salesmen30_40;
-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
@@ -414,17 +414,17 @@ INSERT INTO sales VALUES (40, 50, '2022-03-04');
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition of partitioned table with triggers
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen(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_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
+CREATE TABLE salesmen10_40 PARTITION OF salesmen FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -433,115 +433,115 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salesmen_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salesmen_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salesmen
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salesmen');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salesmen VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
+INSERT INTO salesmen10_40 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40));
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salesmen VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+INSERT INTO salesmen30_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salesmen01_10;
+SELECT * FROM salesmen10_20;
+SELECT * FROM salesmen20_30;
+SELECT * FROM salesmen30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salesmen1_2 PARTITION OF salesmen FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+CREATE TABLE salesmen2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
+ALTER TABLE salesmen ATTACH PARTITION salesmen2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+INSERT INTO salesmen (salesman_name) VALUES ('Poirot');
+INSERT INTO salesmen (salesman_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen1_2'::regclass::oid;
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen2_5'::regclass::oid;
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ALTER TABLE salesmen SPLIT PARTITION salesmen2_5 INTO
+ (PARTITION salesmen2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salesmen3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salesmen4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+INSERT INTO salesmen (salesman_name) VALUES ('May');
+INSERT INTO salesmen (salesman_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
-SELECT * FROM salesmans2_3;
-SELECT * FROM salesmans3_4;
-SELECT * FROM salesmans4_5;
+SELECT * FROM salesmen1_2;
+SELECT * FROM salesmen2_3;
+SELECT * FROM salesmen3_4;
+SELECT * FROM salesmen4_5;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen1_2'::regclass::oid;
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmen4_5'::regclass::oid;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split partition with deleted columns
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salesmen(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 salesmen01_10 PARTITION OF salesmen FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+CREATE TABLE salesmen10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+INSERT INTO salesmen10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salesmen10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salesmen10_40 DROP COLUMN d1;
+ALTER TABLE salesmen10_40 DROP COLUMN d2;
+ALTER TABLE salesmen10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+ALTER TABLE salesmen ATTACH PARTITION salesmen10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salesmen VALUES (1, 'Poirot');
+INSERT INTO salesmen VALUES (10, 'May');
+INSERT INTO salesmen VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salesmen SPLIT PARTITION salesmen10_40 INTO
+ (PARTITION salesmen10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salesmen20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salesmen30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
-select * from salesmans10_20;
-select * from salesmans20_30;
-select * from salesmans30_40;
+select * from salesmen01_10;
+select * from salesmen10_20;
+select * from salesmen20_30;
+select * from salesmen30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salesmen CASCADE;
--
-- Test: split sub-partition
--
2.39.3 (Apple Git-145)
v6-0003-Fix-error-message-in-check_partition_bounds_for_s.patchapplication/octet-stream; name=v6-0003-Fix-error-message-in-check_partition_bounds_for_s.patchDownload
From 2a2742ca3d99e6ce3471e43e9062144e12bd8ecc Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:56:51 +0300
Subject: [PATCH v6 3/4] Fix error message in
check_partition_bounds_for_split_range()
Currently, the error message is produced by a system of complex substitutions
making it quite untranslatable and hard to read. This commit splits this into
4 plain error messages suitable for translation.
Reported-by: Kyotaro Horiguchi
Discussion: https://postgr.es/m/20240408.152402.1485994009160660141.horikyota.ntt%40gmail.com
---
src/backend/partitioning/partbounds.c | 60 +++++++++++++++++----------
1 file changed, 39 insertions(+), 21 deletions(-)
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 0dbacf39c05..bfb965fb2c6 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5211,7 +5211,7 @@ check_partition_bounds_for_split_range(Relation parent,
if (first || last)
{
PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
- bool overlap = false;
+ PartitionRangeDatum *datum;
if (first)
{
@@ -5224,13 +5224,30 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
lower->datums, lower->kind,
true, split_lower);
+ datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
/*
* Lower bound of "spec" should be equal (or greater than or equal
* in case defaultPart=true) to lower bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
- overlap = true;
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ if (cmpval < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
}
else
{
@@ -5243,29 +5260,30 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
upper->datums, upper->kind,
false, split_upper);
+ datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
/*
* Upper bound of of "spec" should be equal (or less than or equal
* in case defaultPart=true) to upper bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
- overlap = true;
- }
-
- if (overlap)
- {
- PartitionRangeDatum *datum;
-
- datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
-
- ereport(ERROR,
- (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
- first ? "lower" : "upper",
- relname,
- defaultPart ? (first ? "less than" : "greater than") : "not equal to",
- first ? "lower" : "upper"),
- parser_errposition(pstate, datum->location)));
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ if (cmpval > 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
}
}
}
--
2.39.3 (Apple Git-145)
v6-0001-Add-missing-CommandCounterIncrement-to-ATExecMerg.patchapplication/octet-stream; name=v6-0001-Add-missing-CommandCounterIncrement-to-ATExecMerg.patchDownload
From 31a493af6a3a7788adea207ede7a63c9192a45a6 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:27:39 +0300
Subject: [PATCH v6 1/4] Add missing CommandCounterIncrement() to
ATExecMergePartitions()
During the MERGE PARTITIONS operation, increment the command counter before
attaching the new partition to the parent. Otherwise, the new catalog tuple
wouldn't be visible. In turn, that could lead to inappropriate index names.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/edfbd846-dcc1-42d1-ac26-715691b687d3%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
src/backend/commands/tablecmds.c | 20 +++++++++++++------
src/test/regress/expected/partition_merge.out | 18 +++++++++++++++++
src/test/regress/sql/partition_merge.sql | 18 +++++++++++++++++
3 files changed, 50 insertions(+), 6 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 027d68e5d2a..87427ad7d2e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21494,12 +21494,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21526,10 +21520,24 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* visible for rename.
*/
CommandCounterIncrement();
+
/* Rename partition. */
RenameRelationInternal(RelationGetRelid(newPartRel),
cmd->name->relname, false, false);
+
+ /*
+ * Bump the command counter to make the tuple of renamed partition
+ * visible for attach partition operation.
+ */
+ CommandCounterIncrement();
}
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 373d32948ca..3593720731c 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,4 +746,22 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes
+WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
+ indexname
+--------------
+ tp_1_2_i_idx
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 6a0b35b1799..940e6b5a9e5 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,5 +444,23 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname value should be 'tp_1_2_i_idx'.
+SELECT indexname FROM pg_indexes
+WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
--
2.39.3 (Apple Git-145)
Hi Alexander,
18.04.2024 13:35, Alexander Korotkov wrote:
The revised patchset is attached.
1) I've split the fix for the CommandCounterIncrement() issue and the
fix for relation persistence issue into a separate patch.
2) I've validated that the lock on the new partition is held in
createPartitionTable() after ProcessUtility() as pointed out by
Robert. So, no need to place the lock again.
3) Added fix for problematic error message as a separate patch [1].
4) Added rename "salemans" => "salesmen" for tests as a separate patch.I think these fixes are reaching committable shape, but I'd like
someone to check it before I push.
I think the feature implementation should also provide tab completion for
SPLIT/MERGE.
(ALTER TABLE t S<Tab>
fills in only SET now.)
Also, the following MERGE operation:
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);
ALTER TABLE t MERGE PARTITIONS (tp_0, tp_1) INTO tp_0;
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"
Best regards,
Alexander
Alexander Lakhin <exclusion@gmail.com> writes:
Hi Alexander,
18.04.2024 13:35, Alexander Korotkov wrote:
The revised patchset is attached.
1) I've split the fix for the CommandCounterIncrement() issue and the
fix for relation persistence issue into a separate patch.
2) I've validated that the lock on the new partition is held in
createPartitionTable() after ProcessUtility() as pointed out by
Robert. So, no need to place the lock again.
3) Added fix for problematic error message as a separate patch [1].
4) Added rename "salemans" => "salesmen" for tests as a separate patch.I think these fixes are reaching committable shape, but I'd like
someone to check it before I push.I think the feature implementation should also provide tab completion for
SPLIT/MERGE.
(ALTER TABLE t S<Tab>
fills in only SET now.)
Here's a patch for that. One thing I noticed while testing it was that
the tab completeion for partitions (Query_for_partition_of_table) shows
all the schemas in the DB, even ones that don't contain any partitions
of the table being altered.
- ilmari
Attachments:
0001-Add-tab-completion-for-ALTER-TABLE-SPLIT-MERGE-PARTI.patchtext/x-diffDownload
From 26db03b7a7675aa7dbff1f18ee084296caa1e181 Mon Sep 17 00:00:00 2001
From: =?UTF-8?q?Dagfinn=20Ilmari=20Manns=C3=A5ker?= <ilmari@ilmari.org>
Date: Thu, 18 Apr 2024 17:47:22 +0100
Subject: [PATCH] =?UTF-8?q?Add=20tab=20completion=20for=20ALTER=20TABLE=20?=
=?UTF-8?q?=E2=80=A6=20SPLIT|MERGE=20PARTITION(S)?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
---
src/bin/psql/tab-complete.c | 18 ++++++++++++++++--
1 file changed, 16 insertions(+), 2 deletions(-)
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 6fee3160f0..97cd5d9f62 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2609,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2620,6 +2621,19 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
--
2.39.2
On 2024-Apr-18, Alexander Lakhin wrote:
I think the feature implementation should also provide tab completion
for SPLIT/MERGE.
I don't think that we should be imposing on feature authors or
committers the task of filling in tab-completion for whatever features
they contribute. I mean, if they want to add that, cool; but if not,
somebody else can do that, too. It's not a critical piece.
Now, if we're talking about whether a patch to add tab-completion to a
feature post feature-freeze is acceptable, I think it absolutely is
(even though you could claim that it's a new psql feature). But for
sure we shouldn't mandate that a feature be reverted just because it
lacks tab-completion -- such lack is not an open-item against the
feature in that sense.
--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
"That sort of implies that there are Emacs keystrokes which aren't obscure.
I've been using it daily for 2 years now and have yet to discover any key
sequence which makes any sense." (Paul Thomas)
On Thu, Apr 18, 2024 at 6:35 AM Alexander Korotkov <aekorotkov@gmail.com> wrote:
The revised patchset is attached.
1) I've split the fix for the CommandCounterIncrement() issue and the
fix for relation persistence issue into a separate patch.
2) I've validated that the lock on the new partition is held in
createPartitionTable() after ProcessUtility() as pointed out by
Robert. So, no need to place the lock again.
3) Added fix for problematic error message as a separate patch [1].
4) Added rename "salemans" => "salesmen" for tests as a separate patch.I think these fixes are reaching committable shape, but I'd like
someone to check it before I push.
Reviewing 0001:
- Seems mostly fine. I think the comment /* Unlock and drop merged
partitions. */ is wrong. I think it should say something like /* Drop
the current partitions before adding the new one. */ because (a) it
doesn't unlock anything, and there's another comment saying that and
(b) we now know that the drop vs. add order matters.
Reviewing 0002:
- Commit message typos: behavious, corresponsing
- Given the change to the header comment of createPartitionTable, it's
rather surprising to me that this patch doesn't touch the
documentation. Isn't that a big change in semantics?
- My previous review comment was really about the code comment, I
believe, rather than the use of AccessExclusiveLock. NoLock is
probably fine, but if it were me I'd be tempted to write
AccessExclusiveLock and just make the comment say something like /* We
should already have the lock, but do it this way just to be certain
*/. But what you have is probably fine, too. Mostly, I want to clarify
the intent of my previous comment.
- Do we, or can we, have a test that if you split a partition that's
not in the search path, the resulting partitions end up in your
creation namespace? And similarly for merge? And maybe also that
schema-qualification works properly?
I haven't exhaustively verified the patch, but these are some things I
noticed when scrolling through it.
Reviewing 0003:
- Are you sure this can't dereference datum when datum is NULL, in
either the upper or lower half? It sure looks strange to have code
that looks like it can make datum a null pointer, and then an
unconditional deference just after.
- In general I think the wording changes are improvements. I'm
slightly suspicious that there might be an even better way to word it,
but I can't think of it right at this very moment.
- I'm kind of unhappy (but not totally unhappy) with the semantics.
Suppose I have a partition that allows values from 0 to 1000, but
actually only contains values that are either between 0 and 99 or
between 901 and 1000. If I try to to split the partition into one that
allows 0..100 and a second that allows 900..1000, it will fail. Maybe
that's good, because that means that if a failure is going to happen,
it will happen right at the beginning, rather than maybe after doing a
lot of work. But on the other hand, it also kind of stinks, because it
feels like I'm being told I can't do something that I know is
perfectly fine.
Reviewing 0004:
- Obviously this is quite trivial and there's no real problem with it,
but if we're changing it anyway, how about a gender-neutral term
(salesperson/salespeople)?
--
Robert Haas
EDB: http://www.enterprisedb.com
Here are some additional fixes to docs.
Attachments:
0001-doc-review-for-ALTER-TABLE-.-SPLIT-MERGE-PARTITION.patchtext/x-diff; charset=us-asciiDownload
From 6da8beaa5a2b78e785e5b6519894f8357002d916 Mon Sep 17 00:00:00 2001
From: Justin Pryzby <pryzbyj@telsasoft.com>
Date: Thu, 18 Apr 2024 15:40:44 -0500
Subject: [PATCH] doc review for ALTER TABLE ... SPLIT/MERGE PARTITION
---
doc/src/sgml/ddl.sgml | 4 ++--
doc/src/sgml/ref/alter_table.sgml | 22 +++++++++++-----------
2 files changed, 13 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 026bfff70f3..01277b1d327 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4384,7 +4384,7 @@ ALTER INDEX measurement_city_id_logdate_key
<para>
There is also an option for merging multiple table partitions into
- a single partition using the
+ a single partition using
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
users to combine partitions that are no longer needed as
@@ -4403,7 +4403,7 @@ ALTER TABLE measurement
<para>
Similarly to merging multiple table partitions, there is an option for
- splitting a single partition into multiple using the
+ splitting a single partition into multiple partitions using
<link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
This feature could come in handy when one partition grows too big
and needs to be split into multiple. It's important to note that
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index fe36ff82e52..e52cfee840c 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1136,16 +1136,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
In case one of the new partitions or one of existing partitions is DEFAULT,
new partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have gaps
between partitions bounds. If the partitioned table does not have a DEFAULT
partition, the DEFAULT partition can be defined as one of the new partitions.
</para>
<para>
In case new partitions do not contain a DEFAULT partition and the partitioned table
- does not have a DEFAULT partition, the following must be true: sum bounds of
+ does not have a DEFAULT partition, the following must be true: the sum bounds of
new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... should be
- equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ equal to the bounds of split partition <replaceable class="parameter">partition_name</replaceable>.
One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... can have
the same name as split partition <replaceable class="parameter">partition_name</replaceable>
@@ -1168,24 +1168,24 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
- This form merges several partitions into the one partition of the target table.
- Hash-partitioning is not supported. If DEFAULT partition is not in the
+ This form merges several partitions of the target table into a single partition.
+ Hash-partitioning is not supported. If a DEFAULT partition is not in the
list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables it is necessary that the ranges
+ For range-partitioned tables, it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
- be merged into one range without spaces and overlaps (otherwise an error
+ be merged into one range with neither gaps nor overlaps (otherwise an error
will be generated). The combined range will be the range for the partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
<listitem>
<para>
- For list-partitioned tables the value lists of all partitions
+ For list-partitioned tables, the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
combined and form the list of values of partition
@@ -1193,7 +1193,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
</listitem>
</itemizedlist>
- If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ If a DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
@@ -1204,8 +1204,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For range- and list-partitioned tables the ranges and lists of values
- of the merged partitions can be any.
+ For range- and list-partitioned tables, the ranges and lists of values
+ of the merged partitions can be anything.
</para>
</listitem>
</itemizedlist>
--
2.42.0
Hi!
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"
Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patch
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v6-0005-Fix.patchtext/plain; charset=UTF-8; name=v6-0005-Fix.patchDownload
From 58e4b7fb1d3b15cdf1c742c28690392dda34915d Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Fri, 19 Apr 2024 01:57:49 +0300
Subject: [PATCH v6] Fix
---
src/backend/commands/tablecmds.c | 49 ++++++-------------
src/test/regress/expected/partition_merge.out | 13 ++++-
src/test/regress/sql/partition_merge.sql | 8 ++-
3 files changed, 33 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 72874295cb..8985747180 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21508,9 +21508,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
- char tmpRelName[NAMEDATALEN];
- RangeVar *mergePartName = cmd->name;
- bool isSameName = false;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -21532,8 +21529,22 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* function transformPartitionCmdForMerge().
*/
if (equal(name, cmd->name))
+ {
/* One new partition can have the same name as merged partition. */
- isSameName = true;
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /* Rename partition. */
+ RenameRelationInternal(RelationGetRelid(mergingPartition),
+ tmpRelName, false, false);
+ /*
+ * We must bump the command counter to make the new partition tuple
+ * visible for rename.
+ */
+ CommandCounterIncrement();
+ }
/* Store a next merging partition into the list. */
mergingPartitionsList = lappend(mergingPartitionsList,
@@ -21553,16 +21564,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- /* Create table for new partition, use partitioned table as model. */
- if (isSameName)
- {
- /* Create partition table with generated temporary name. */
- sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(cmd->name->schemaname, tmpRelName, -1);
- }
-
newPartRel = createPartitionTable(rel,
- mergePartName,
+ cmd->name,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21588,26 +21591,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
list_free(mergingPartitionsList);
- /* 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);
-
- /*
- * Bump the command counter to make the tuple of renamed partition
- * visible for attach partition operation.
- */
- CommandCounterIncrement();
- }
-
/*
* Attach a new partition to the partitioned table. wqueue = NULL:
* verification for each cloned constraint is not needed.
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index b5744ed498..2499a314fb 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -779,17 +779,26 @@ DROP TABLE t;
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
-CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
--- Indexname value should be 'tp_1_2_i_idx'.
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
SELECT indexname FROM pg_indexes
WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
indexname
--------------
+ tp_1_2_pkey
tp_1_2_i_idx
+(2 rows)
+
+-- Conname value should be 'tp_1_2_i_not_null'.
+SELECT conname FROM pg_constraint
+WHERE conrelid='tp_1_2'::regclass AND contype='n';
+ conname
+-------------------
+ tp_1_2_i_not_null
(1 row)
DROP TABLE t;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index df737e214e..6614512f69 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -470,7 +470,7 @@ DROP TABLE t;
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
-CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
@@ -478,10 +478,14 @@ CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
--- Indexname value should be 'tp_1_2_i_idx'.
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
SELECT indexname FROM pg_indexes
WHERE tablename = 'tp_1_2' AND schemaname = 'partitions_merge_schema';
+-- Conname value should be 'tp_1_2_i_not_null'.
+SELECT conname FROM pg_constraint
+WHERE conrelid='tp_1_2'::regclass AND contype='n';
+
DROP TABLE t;
--
--
2.40.1.windows.1
18.04.2024 20:49, Alvaro Herrera wrote:
On 2024-Apr-18, Alexander Lakhin wrote:
I think the feature implementation should also provide tab completion
for SPLIT/MERGE.I don't think that we should be imposing on feature authors or
committers the task of filling in tab-completion for whatever features
they contribute. I mean, if they want to add that, cool; but if not,
somebody else can do that, too. It's not a critical piece.
I agree, I just wanted to note the lack of the current implementation.
But now, thanks to Dagfinn, we have the tab completion too.
I have also a question regarding "ALTER TABLE ... SET ACCESS METHOD". The
current documentation says:
When applied to a partitioned table, there is no data to rewrite, but
partitions created afterwards will default to the given access method
unless overridden by a USING clause.
But MERGE/SPLIT behave differently (if one can assume that MERGE/SPLIT
create new partitions under the hood):
CREATE ACCESS METHOD heap2 TYPE TABLE HANDLER heap_tableam_handler;
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
ALTER TABLE t SET ACCESS METHOD heap2;
CREATE TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);
\d t+
Partitioned table "public.t"
...
Access method: heap2
Table "public.tp_0"
...
Access method: heap2
Table "public.tp_1"
...
Access method: heap2
ALTER TABLE t MERGE PARTITIONS (tp_0, tp_1) INTO tp_0;
Partitioned table "public.t"
...
Access method: heap2
Table "public.tp_0"
...
Access method: heap
Shouldn't it be changed, what do you think?
Best regards,
Alexander
On Thu, Apr 11, 2024 at 10:20:53PM -0400, Robert Haas wrote:
On Thu, Apr 11, 2024 at 9:54 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
I think we shouldn't unconditionally copy schema name and
relpersistence from the parent table. Instead we should throw the
error on a mismatch like CREATE TABLE ... PARTITION OF ... does. I'm
working on revising this fix.We definitely shouldn't copy the schema name from the parent table. It
should be possible to schema-qualify the new partition names, and if
you don't, then the search_path should determine where they get
placed.
+1. Alexander Lakhin reported an issue with schemas and SPLIT, and I
noticed an issue with schemas with MERGE. The issue I hit is occurs
when MERGE'ing into a partition with the same name, and it's fixed like
so:
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21526,8 +21526,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
/* Create partition table with generated temporary name. */
sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- tmpRelName, -1);
+ mergePartName = makeRangeVar(mergePartName->schemaname, tmpRelName, -1);
}
createPartitionTable(mergePartName,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
One of the things I dislike about this type of feature -- not this
implementation specifically, but just this kind of idea in general --
is that the syntax mentions a whole bunch of tables but in a way where
you can't set their properties. Persistence, reloptions, whatever.
There's just no place to mention any of that stuff - and if you wanted
to create a place, you'd have to invent special syntax for each
separate thing. That's why I think it's good that the normal way of
creating a partition is CREATE TABLE .. PARTITION OF. Because that
way, we know that the full power of the CREATE TABLE statement is
always available, and you can set anything that you could set for a
table that is not a partition.
Right. The current feature is useful and will probably work for 90% of
people's partitioned tables.
Currently, CREATE TABLE .. PARTITION OF does not create stats objects on
the child table, but MERGE PARTITIONS does, which seems strange.
Maybe stats should not be included on the new child ?
Note that stats on parent table are not analagous to indexes -
partitioned indexes do nothing other than cause indexes to be created on
any new/attached partitions. But stats objects on the parent 1) cause
extended stats to be collected and computed across the whole partition
heirarchy, and 2) do not cause stats to be computed for the individual
partitions.
Partitions can have different column definitions, for example null
constraints, FKs, defaults. And currently, if you MERGE partitions,
those will all be lost (or rather, replaced by whatever LIKE parent
gives). I think that's totally fine - anyone using different defaults
on child tables could either not use MERGE PARTITIONS, or fix up the
defaults afterwards. There's not much confusion that the details of the
differences between individual partitions will be lost when the
individual partitions are merged and no longer exist.
But I think it'd be useful to document how the new partitions will be
constructed.
--
Justin
On Fri, Apr 19, 2024 at 2:26 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patch
I've incorporated this fix with 0001 patch.
Also added to the patchset
005 – tab completion by Dagfinn [1]
006 – draft fix for table AM issue spotted by Alexander Lakhin [2]
007 – doc review by Justin [3]
I'm continuing work on this.
Links
1. /messages/by-id/87plumiox2.fsf@wibble.ilmari.org
2. /messages/by-id/84ada05b-be5c-473e-6d1c-ebe5dd21b190@gmail.com
3. /messages/by-id/ZiGH0xc1lxJ71ZfB@pryzbyj2023
------
Regards,
Alexander Korotkov
Attachments:
v7-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchapplication/octet-stream; name=v7-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchDownload
From be331b8793b92fed797b76b48acb231c405c4a1a Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 19 Apr 2024 13:39:45 +0300
Subject: [PATCH v7 1/7] Change the way ATExecMergePartitions() handles the
name collision
The name collision happens when the name of the new partition is the same as
the name of one of the merging partitions. Currently, ATExecMergePartitions()
first gives the new partition a temporary name and then renames it when old
partitions are deleted. That negatively influences the naming of related
objects like indexes and constrains, which could inherit a temporary name.
This commit changes the implementation in the following way. A merging
partition gets renamed first, then the new partition is created with the
right name immediately. This resolves the issue of the naming of related
objects.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/edfbd846-dcc1-42d1-ac26-715691b687d3%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
src/backend/commands/tablecmds.c | 61 +++++++++----------
src/test/regress/expected/partition_merge.out | 25 ++++++++
src/test/regress/sql/partition_merge.sql | 18 ++++++
3 files changed, 72 insertions(+), 32 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index fbffaef1966..0f72ffa9abc 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21476,9 +21476,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
- char tmpRelName[NAMEDATALEN];
- RangeVar *mergePartName = cmd->name;
- bool isSameName = false;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -21500,8 +21497,28 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* function transformPartitionCmdForMerge().
*/
if (equal(name, cmd->name))
+ {
/* One new partition can have the same name as merged partition. */
- isSameName = true;
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(mergingPartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
/* Store a next merging partition into the list. */
mergingPartitionsList = lappend(mergingPartitionsList,
@@ -21521,15 +21538,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- /* Create table for new partition, use partitioned table as model. */
- if (isSameName)
- {
- /* Create partition table with generated temporary name. */
- sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- tmpRelName, -1);
- }
- createPartitionTable(mergePartName,
+ createPartitionTable(cmd->name,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21540,17 +21549,11 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* excessive, but this is the way we make sure nobody is planning queries
* involving merging partitions.
*/
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the 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, mergingPartitionsList)
{
@@ -21569,18 +21572,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
list_free(mergingPartitionsList);
- /* 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);
- }
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 373d32948ca..2e0bfdc705d 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,4 +746,29 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "tp_1_2_i_not_null" NOT NULL "i"
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 6a0b35b1799..72b1cb0b35e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,5 +444,23 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
--
2.39.3 (Apple Git-145)
v7-0002-Verify-persistence-of-new-partitions-during-MERGE.patchapplication/octet-stream; name=v7-0002-Verify-persistence-of-new-partitions-during-MERGE.patchDownload
From ca4d010f40b1c10cfb72d72e41fda3c992f66235 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:41:09 +0300
Subject: [PATCH v7 2/7] Verify persistence of new partitions during
MERGE/SPLIT operations
The createPartitionTable() function is responsible for creating new partitions
for ALTER TABLE ... MERGE PARTITIONS, and ALTER TABLE ... SPLIT PARTITION
commands. It emulates the behaviour of CREATE TABLE ... (LIKE ...), but
lacks of check for the result relation persistence. This commit adds
corresponding check similarly to what we have for CREATE TABLE ...
PARTITION OF command.
This commit also changes the signature of createPartitionTable() making it
take the parent's Relation itself instead of the name of the parent relation,
and return the Relation of new partition. That doesn't lead to
complications, because both callers have the parent table open and need to
open the new partition.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/dbc8b96c-3cf0-d1ee-860d-0e491da20485%40gmail.com
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
src/backend/commands/tablecmds.c | 70 +++++++++------
src/test/regress/expected/partition_merge.out | 89 +++++++++++++++++++
src/test/regress/expected/partition_split.out | 29 ++++++
src/test/regress/sql/partition_merge.sql | 68 ++++++++++++++
src/test/regress/sql/partition_split.sql | 23 +++++
5 files changed, 254 insertions(+), 25 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 0f72ffa9abc..2025e68bdae 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21182,18 +21182,27 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* createPartitionTable: create table for a new partition with given name
- * (newPartName) like table (modelRelName)
+ * (newPartName) like table (modelRel)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
@@ -21206,7 +21215,8 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
createStmt->if_not_exists = false;
tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
/*
* Indexes will be inherited on "attach new partitions" stage, after data
@@ -21232,6 +21242,33 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL,
None_Receiver,
NULL);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * If the parent is permanent, so must be all of its partitions. Note
+ * that inheritance allows that case.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot inherit from temporary ones */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
}
/*
@@ -21251,7 +21288,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
char tmpRelName[NAMEDATALEN];
List *newPartRels = NIL;
ObjectAddress object;
- RangeVar *parentName;
Oid defaultPartOid;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -21323,18 +21359,12 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create new partitions (like split partition), without indexes. */
- parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1);
foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
+ newPartRel = createPartitionTable(sps->name, rel, context);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21538,18 +21568,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- createPartitionTable(cmd->name,
- makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1),
- context);
-
- /*
- * Open the new partition and acquire exclusive lock on it. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2e0bfdc705d..cf961b041fb 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,6 +746,36 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
@@ -771,4 +801,63 @@ Not-null constraints:
DROP TABLE t;
--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = public, pg_temp;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+RESET search_path;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = public, pg_temp;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 419d169f036..660361cd20e 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1427,4 +1427,33 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 72b1cb0b35e..29ae6a09f13 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,6 +444,28 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
@@ -462,5 +484,51 @@ ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b63532ee562..576f9f0f63c 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -844,5 +844,28 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
v7-0005-Add-tab-completion-for-ALTER-TABLE-SPLIT-MERGE-PA.patchapplication/octet-stream; name=v7-0005-Add-tab-completion-for-ALTER-TABLE-SPLIT-MERGE-PA.patchDownload
From f20d063f436b126da5ef0b78f0fb90b698c965eb Mon Sep 17 00:00:00 2001
From: =?UTF-8?q?Dagfinn=20Ilmari=20Manns=C3=A5ker?= <ilmari@ilmari.org>
Date: Thu, 18 Apr 2024 17:47:22 +0100
Subject: [PATCH v7 5/7] =?UTF-8?q?Add=20tab=20completion=20for=20ALTER=20T?=
=?UTF-8?q?ABLE=20=E2=80=A6=20SPLIT|MERGE=20PARTITION(S)?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
---
src/bin/psql/tab-complete.c | 18 ++++++++++++++++--
1 file changed, 16 insertions(+), 2 deletions(-)
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 6fee3160f02..97cd5d9f628 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2609,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2620,6 +2621,19 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
--
2.39.3 (Apple Git-145)
v7-0003-Fix-error-message-in-check_partition_bounds_for_s.patchapplication/octet-stream; name=v7-0003-Fix-error-message-in-check_partition_bounds_for_s.patchDownload
From 204321a37aa69273a6438e26163eb769d49cac47 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:56:51 +0300
Subject: [PATCH v7 3/7] Fix error message in
check_partition_bounds_for_split_range()
Currently, the error message is produced by a system of complex substitutions
making it quite untranslatable and hard to read. This commit splits this into
4 plain error messages suitable for translation.
Reported-by: Kyotaro Horiguchi
Discussion: https://postgr.es/m/20240408.152402.1485994009160660141.horikyota.ntt%40gmail.com
---
src/backend/partitioning/partbounds.c | 60 +++++++++++++++++----------
1 file changed, 39 insertions(+), 21 deletions(-)
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b08edf87a69..6c04d8bef5b 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5211,7 +5211,7 @@ check_partition_bounds_for_split_range(Relation parent,
if (first || last)
{
PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
- bool overlap = false;
+ PartitionRangeDatum *datum;
if (first)
{
@@ -5224,13 +5224,30 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
lower->datums, lower->kind,
true, split_lower);
+ datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
/*
* Lower bound of "spec" should be equal (or greater than or equal
* in case defaultPart=true) to lower bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
- overlap = true;
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ if (cmpval < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
}
else
{
@@ -5243,29 +5260,30 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
upper->datums, upper->kind,
false, split_upper);
+ datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
/*
* Upper bound of "spec" should be equal (or less than or equal in
* case defaultPart=true) to upper bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
- overlap = true;
- }
-
- if (overlap)
- {
- PartitionRangeDatum *datum;
-
- datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
-
- ereport(ERROR,
- (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
- first ? "lower" : "upper",
- relname,
- defaultPart ? (first ? "less than" : "greater than") : "not equal to",
- first ? "lower" : "upper"),
- parser_errposition(pstate, datum->location)));
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ else
+ {
+ if (cmpval > 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
}
}
}
--
2.39.3 (Apple Git-145)
v7-0004-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchapplication/octet-stream; name=v7-0004-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchDownload
From e985c103b43cd6d31da294d8541407dc0c8dc131 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 19 Apr 2024 16:03:06 +0300
Subject: [PATCH v7 4/7] Rename tables in tests of partition MERGE/SPLIT
operations
Replace "salesman" with "salesperson", "salesmen" with "salespeople". The
names are both gramatically correct and gender-neutral.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/fdaa003e-919c-cbc9-4f0c-e4546e96bd65%40gmail.com
Reviewed-by: Robert Haas
---
src/test/regress/expected/partition_merge.out | 676 ++++-----
src/test/regress/expected/partition_split.out | 1238 ++++++++---------
src/test/regress/sql/partition_merge.sql | 160 +--
src/test/regress/sql/partition_split.sql | 280 ++--
4 files changed, 1177 insertions(+), 1177 deletions(-)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index cf961b041fb..acacd81767c 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -10,12 +10,12 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -54,7 +54,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -115,68 +115,68 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemanam
(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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
-- Use indexscan for testing indexes
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
+ salesperson_id | salesperson_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)
RESET enable_seqscan;
@@ -184,7 +184,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -209,15 +209,15 @@ INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
-- 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
+ salesperson_id | salesperson_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:
@@ -239,7 +239,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -248,219 +248,219 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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;
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_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
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
- 20 | Smirnoff
- 31 | Popov
- 30 | Ford
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
(5 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -482,88 +482,88 @@ 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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;
@@ -574,8 +574,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -607,33 +607,33 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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
@@ -662,68 +662,68 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
(3 rows)
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 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 | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_all;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
RESET enable_seqscan;
@@ -803,7 +803,7 @@ DROP TABLE t;
--
-- Try mixing permanent and temporary partitions.
--
-SET search_path = public, pg_temp;
+SET search_path = partitions_merge_schema, pg_temp, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
@@ -823,16 +823,16 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
tp_1_2 | FOR VALUES FROM (1) TO (2) | p
(2 rows)
-SET search_path = pg_temp, public;
+SET search_path = pg_temp, partitions_merge_schema, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ERROR: cannot create a temporary relation as partition of permanent relation "t"
-RESET search_path;
+SET search_path = partitions_merge_schema, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
ERROR: cannot create a temporary relation as partition of permanent relation "t"
DROP TABLE t;
-SET search_path = pg_temp, public;
+SET search_path = pg_temp, partitions_merge_schema, public;
BEGIN;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
@@ -853,7 +853,7 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
tp_1_2 | FOR VALUES FROM (1) TO (2) | t
(2 rows)
-SET search_path = public, pg_temp;
+SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ERROR: cannot create a permanent relation as partition of temporary relation "t"
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 660361cd20e..ed25ff08d9f 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -10,7 +10,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -84,8 +84,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
- ^
+LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -109,7 +109,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -132,68 +132,68 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -216,61 +216,61 @@ 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
- 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
@@ -280,7 +280,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -288,103 +288,103 @@ CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month
CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
(4 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
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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
- Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
(3 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
- Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
(3 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
+ salesperson_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)
--ERROR: relation "sales_jan_feb2022" does not exist
@@ -396,7 +396,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -415,19 +415,19 @@ 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_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-10-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 6 | Poirot | 150 | 02-11-2022
- 7 | Li | 175 | 03-08-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 11 | Trump | 380 | 04-06-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(11 rows)
SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
@@ -445,34 +445,34 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 11 | Trump | 380 | 04-06-2022
- 5 | Deev | 250 | 04-07-2022
- 4 | Ivanov | 750 | 04-13-2022
- 3 | Ford | 2000 | 04-30-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
(4 rows)
SELECT * FROM sales_others where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -505,7 +505,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
@@ -562,7 +562,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -574,20 +574,20 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -596,50 +596,50 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
INSERT INTO sales VALUES (10, 150, '2022-03-01');
@@ -648,280 +648,280 @@ INSERT INTO sales VALUES (19, 200, '2022-03-04');
INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans2_3;
- salesman_id | salesman_name
--------------+---------------
- 2 | Ivanov
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
(1 row)
-SELECT * FROM salesmans3_4;
- salesman_id | salesman_name
--------------+---------------
- 3 | May
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
(1 row)
-SELECT * FROM salesmans4_5;
- salesman_id | salesman_name
--------------+---------------
- 4 | Ford
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
(1 row)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
(2 rows)
-select * from salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-select * from salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
@@ -941,31 +941,31 @@ 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
- 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
+ salesperson_id | salesperson_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_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
@@ -973,50 +973,50 @@ ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
(1 row)
DROP TABLE sales_range;
@@ -1027,8 +1027,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1067,8 +1067,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1092,109 +1092,109 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(14 rows)
SELECT * FROM sales_west;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(4 rows)
SELECT * FROM sales_east;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
(2 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 | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_central;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -1205,7 +1205,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
@@ -1228,42 +1228,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(8 rows)
DROP TABLE sales_range;
@@ -1272,7 +1272,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1295,42 +1295,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
(8 rows)
DROP TABLE sales_range;
@@ -1338,7 +1338,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1360,56 +1360,56 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_others DEFAULT);
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
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-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
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
(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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(4 rows)
DROP TABLE sales_range;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 29ae6a09f13..9e21d8b163f 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -13,13 +13,13 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -50,7 +50,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -108,7 +108,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -151,7 +151,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -162,15 +162,15 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -180,8 +180,8 @@ 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -193,14 +193,14 @@ 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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_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);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -209,80 +209,80 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_20 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (30, 'Ford');
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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));
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_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');
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_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 salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_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);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_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');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-select * from salesmans;
-select * from salesmans01_10;
-select * from salesmans10_40;
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -329,8 +329,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -366,14 +366,14 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
@@ -382,20 +382,20 @@ CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi'
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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)
@@ -420,7 +420,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
RESET enable_seqscan;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 576f9f0f63c..4228917654c 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -13,7 +13,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -98,7 +98,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -135,7 +135,7 @@ DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -175,7 +175,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -185,15 +185,15 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1)
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -204,8 +204,8 @@ ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -221,7 +221,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -272,7 +272,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
@@ -322,7 +322,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
@@ -337,11 +337,11 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
sales_date DATE) PARTITION BY RANGE (sales_date);
@@ -363,28 +363,28 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
@@ -395,36 +395,36 @@ INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition of partitioned table with triggers
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -433,125 +433,125 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
-SELECT * FROM salesmans2_3;
-SELECT * FROM salesmans3_4;
-SELECT * FROM salesmans4_5;
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition with deleted columns
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
-select * from salesmans10_20;
-select * from salesmans20_30;
-select * from salesmans30_40;
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
@@ -598,8 +598,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -635,8 +635,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -663,34 +663,34 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
@@ -709,7 +709,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
SET enable_indexscan = ON;
SET enable_seqscan = ON;
@@ -721,7 +721,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -759,7 +759,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -796,7 +796,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
--
2.39.3 (Apple Git-145)
v7-0006-ALTER-TABLE-.-MERGE-PARTITIONS-.-make-inherit-par.patchapplication/octet-stream; name=v7-0006-ALTER-TABLE-.-MERGE-PARTITIONS-.-make-inherit-par.patchDownload
From 11f4b57db9e381745a107d3f49e796afd5e8924e Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 19 Apr 2024 14:55:24 +0300
Subject: [PATCH v7 6/7] ALTER TABLE ... MERGE PARTITIONS ... make inherit
parent's am
Reported-by:
Bug:
Discussion:
Author:
Reviewed-by:
Tested-by:
Backpatch-through:
---
src/backend/commands/tablecmds.c | 6 ++++++
1 file changed, 6 insertions(+)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 2025e68bdae..575e99509d8 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21186,6 +21186,11 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
@@ -21213,6 +21218,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
createStmt->oncommit = ONCOMMIT_NOOP;
createStmt->tablespacename = NULL;
createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
tlc = makeNode(TableLikeClause);
tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
--
2.39.3 (Apple Git-145)
v7-0007-doc-review-for-ALTER-TABLE-.-SPLIT-MERGE-PARTITIO.patchapplication/octet-stream; name=v7-0007-doc-review-for-ALTER-TABLE-.-SPLIT-MERGE-PARTITIO.patchDownload
From 9be4d11f85fd4adac924b40eded963e74bb55171 Mon Sep 17 00:00:00 2001
From: Justin Pryzby <pryzbyj@telsasoft.com>
Date: Thu, 18 Apr 2024 15:40:44 -0500
Subject: [PATCH v7 7/7] doc review for ALTER TABLE ... SPLIT/MERGE PARTITION
---
doc/src/sgml/ddl.sgml | 4 ++--
doc/src/sgml/ref/alter_table.sgml | 22 +++++++++++-----------
2 files changed, 13 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 026bfff70f3..01277b1d327 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4384,7 +4384,7 @@ ALTER INDEX measurement_city_id_logdate_key
<para>
There is also an option for merging multiple table partitions into
- a single partition using the
+ a single partition using
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
users to combine partitions that are no longer needed as
@@ -4403,7 +4403,7 @@ ALTER TABLE measurement
<para>
Similarly to merging multiple table partitions, there is an option for
- splitting a single partition into multiple using the
+ splitting a single partition into multiple partitions using
<link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
This feature could come in handy when one partition grows too big
and needs to be split into multiple. It's important to note that
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index fe36ff82e52..e52cfee840c 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1136,16 +1136,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
In case one of the new partitions or one of existing partitions is DEFAULT,
new partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have gaps
between partitions bounds. If the partitioned table does not have a DEFAULT
partition, the DEFAULT partition can be defined as one of the new partitions.
</para>
<para>
In case new partitions do not contain a DEFAULT partition and the partitioned table
- does not have a DEFAULT partition, the following must be true: sum bounds of
+ does not have a DEFAULT partition, the following must be true: the sum bounds of
new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... should be
- equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ equal to the bounds of split partition <replaceable class="parameter">partition_name</replaceable>.
One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... can have
the same name as split partition <replaceable class="parameter">partition_name</replaceable>
@@ -1168,24 +1168,24 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
- This form merges several partitions into the one partition of the target table.
- Hash-partitioning is not supported. If DEFAULT partition is not in the
+ This form merges several partitions of the target table into a single partition.
+ Hash-partitioning is not supported. If a DEFAULT partition is not in the
list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables it is necessary that the ranges
+ For range-partitioned tables, it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
- be merged into one range without spaces and overlaps (otherwise an error
+ be merged into one range with neither gaps nor overlaps (otherwise an error
will be generated). The combined range will be the range for the partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
<listitem>
<para>
- For list-partitioned tables the value lists of all partitions
+ For list-partitioned tables, the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
combined and form the list of values of partition
@@ -1193,7 +1193,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
</listitem>
</itemizedlist>
- If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ If a DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
@@ -1204,8 +1204,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For range- and list-partitioned tables the ranges and lists of values
- of the merged partitions can be any.
+ For range- and list-partitioned tables, the ranges and lists of values
+ of the merged partitions can be anything.
</para>
</listitem>
</itemizedlist>
--
2.39.3 (Apple Git-145)
Hi!
On Fri, Apr 19, 2024 at 4:29 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, Apr 19, 2024 at 2:26 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patchI've incorporated this fix with 0001 patch.
Also added to the patchset
005 – tab completion by Dagfinn [1]
006 – draft fix for table AM issue spotted by Alexander Lakhin [2]
007 – doc review by Justin [3]I'm continuing work on this.
Links
1. /messages/by-id/87plumiox2.fsf@wibble.ilmari.org
2. /messages/by-id/84ada05b-be5c-473e-6d1c-ebe5dd21b190@gmail.com
3. /messages/by-id/ZiGH0xc1lxJ71ZfB@pryzbyj2023
0001
The way we handle name collisions during MERGE PARTITIONS operation is
reworked by integration of patch [3]. This makes note about commit in
[2]: not relevant.
0002
The persistence of the new partition is copied as suggested in [1].
But the checks are in-place, because search_path could influence new
table persistence. Per review [2]not relevant., commit message typos are fixed,
documentation is revised, revised tests to cover schema-qualification,
usage of search_path.
0003
Making code more clear that we're not going to dereference the NULL
datum per note in [2]not relevant..
0004
Gender-neutral terms are used per suggestions in [2]not relevant..
0005
Commit message revised
0006
Revise documentation mentioning we're going to copy the parent's table
AM. Regression tests are added. Commit message revised.
0007
Commit message revised
Links
1. /messages/by-id/CA+TgmoYcjL+w2BQzku5iNXKR5fyxJMSP3avQta8xngioTX7D7A@mail.gmail.com
2. /messages/by-id/CA+TgmoY_4r6BeeSCTim04nAiCmmXg-1pG1toxQovZOP2qaFJ0A@mail.gmail.com
3. /messages/by-id/f8b5cbf5-965e-4e5b-b506-33bbf41b0d50@postgrespro.ru
------
Regards,
Alexander Korotkov
Attachments:
v8-0003-Fix-error-message-in-check_partition_bounds_for_s.patchapplication/octet-stream; name=v8-0003-Fix-error-message-in-check_partition_bounds_for_s.patchDownload
From f1b75b45cb6c7f0070344f4d4e3d7b14b7792733 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:56:51 +0300
Subject: [PATCH v8 3/7] Fix error message in
check_partition_bounds_for_split_range()
Currently, the error message is produced by a system of complex substitutions
making it quite untranslatable and hard to read. This commit splits this into
4 plain error messages suitable for translation.
Reported-by: Kyotaro Horiguchi
Discussion: https://postgr.es/m/20240408.152402.1485994009160660141.horikyota.ntt%40gmail.com
---
src/backend/partitioning/partbounds.c | 71 +++++++++++++++++++--------
1 file changed, 50 insertions(+), 21 deletions(-)
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b08edf87a69..2fb39e3d006 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5211,7 +5211,7 @@ check_partition_bounds_for_split_range(Relation parent,
if (first || last)
{
PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
- bool overlap = false;
+ PartitionRangeDatum *datum;
if (first)
{
@@ -5229,8 +5229,30 @@ check_partition_bounds_for_split_range(Relation parent,
* Lower bound of "spec" should be equal (or greater than or equal
* in case defaultPart=true) to lower bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
- overlap = true;
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
}
else
{
@@ -5243,29 +5265,36 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
upper->datums, upper->kind,
false, split_upper);
+ datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
/*
* Upper bound of "spec" should be equal (or less than or equal in
* case defaultPart=true) to upper bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
- overlap = true;
- }
-
- if (overlap)
- {
- PartitionRangeDatum *datum;
-
- datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
-
- ereport(ERROR,
- (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
- first ? "lower" : "upper",
- relname,
- defaultPart ? (first ? "less than" : "greater than") : "not equal to",
- first ? "lower" : "upper"),
- parser_errposition(pstate, datum->location)));
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
}
}
}
--
2.39.3 (Apple Git-145)
v8-0004-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchapplication/octet-stream; name=v8-0004-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchDownload
From 3b0d557c29c15ded94908114ed7ab1fe7cc1ab75 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 11:31:57 +0300
Subject: [PATCH v8 4/7] Rename tables in tests of partition MERGE/SPLIT
operations
Replace "salesman" with "salesperson", "salesmen" with "salespeople". The
names are both gramatically correct and gender-neutral.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/fdaa003e-919c-cbc9-4f0c-e4546e96bd65%40gmail.com
Reviewed-by: Robert Haas
---
src/test/regress/expected/partition_merge.out | 666 ++++-----
src/test/regress/expected/partition_split.out | 1266 ++++++++---------
src/test/regress/sql/partition_merge.sql | 160 +--
src/test/regress/sql/partition_split.sql | 280 ++--
4 files changed, 1186 insertions(+), 1186 deletions(-)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 3aae5f89e80..a92a270c591 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -11,12 +11,12 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -60,7 +60,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -122,68 +122,68 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemanam
(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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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 partitions_merge_schema2.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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM partitions_merge_schema2.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
+ salesperson_id | salesperson_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)
RESET enable_seqscan;
@@ -191,7 +191,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -216,15 +216,15 @@ INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
-- 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
+ salesperson_id | salesperson_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:
@@ -246,7 +246,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -255,219 +255,219 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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;
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_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
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
- 20 | Smirnoff
- 31 | Popov
- 30 | Ford
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
(5 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -489,88 +489,88 @@ 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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;
@@ -581,8 +581,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -614,33 +614,33 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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
@@ -669,68 +669,68 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
(3 rows)
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 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 | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_all;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
RESET enable_seqscan;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index e2a362ffafd..55ae37ad370 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -11,7 +11,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -85,8 +85,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
- ^
+LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -114,13 +114,13 @@ SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
SET search_path = partition_split_schema, public;
\d+ sales_range
- Partitioned table "partition_split_schema.sales_range"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
- salesman_id | integer | | | | plain | |
- salesman_name | character varying(30) | | | | extended | |
- sales_amount | integer | | | | plain | |
- sales_date | date | | | | plain | |
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
Partition key: RANGE (sales_date)
Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
@@ -132,7 +132,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -155,68 +155,68 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -226,13 +226,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
\d+ sales_range
- Partitioned table "partition_split_schema.sales_range"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
- salesman_id | integer | | | | plain | |
- salesman_name | character varying(30) | | | | extended | |
- sales_amount | integer | | | | plain | |
- sales_date | date | | | | plain | |
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
Partition key: RANGE (sales_date)
Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
@@ -255,61 +255,61 @@ 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
- 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM partition_split_schema2.sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
@@ -319,7 +319,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -327,103 +327,103 @@ CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month
CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
(4 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
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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
- Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
(3 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
- Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
(3 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
+ salesperson_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)
--ERROR: relation "sales_jan_feb2022" does not exist
@@ -435,7 +435,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -454,19 +454,19 @@ 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_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-10-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 6 | Poirot | 150 | 02-11-2022
- 7 | Li | 175 | 03-08-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 11 | Trump | 380 | 04-06-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(11 rows)
SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
@@ -484,34 +484,34 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 11 | Trump | 380 | 04-06-2022
- 5 | Deev | 250 | 04-07-2022
- 4 | Ivanov | 750 | 04-13-2022
- 3 | Ford | 2000 | 04-30-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
(4 rows)
SELECT * FROM sales_others where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -544,7 +544,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
@@ -601,7 +601,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -613,20 +613,20 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -635,50 +635,50 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
INSERT INTO sales VALUES (10, 150, '2022-03-01');
@@ -687,280 +687,280 @@ INSERT INTO sales VALUES (19, 200, '2022-03-04');
INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans2_3;
- salesman_id | salesman_name
--------------+---------------
- 2 | Ivanov
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
(1 row)
-SELECT * FROM salesmans3_4;
- salesman_id | salesman_name
--------------+---------------
- 3 | May
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
(1 row)
-SELECT * FROM salesmans4_5;
- salesman_id | salesman_name
--------------+---------------
- 4 | Ford
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
(1 row)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
(2 rows)
-select * from salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-select * from salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
@@ -980,31 +980,31 @@ 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
- 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
+ salesperson_id | salesperson_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_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
@@ -1012,50 +1012,50 @@ ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
(1 row)
DROP TABLE sales_range;
@@ -1066,8 +1066,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1106,8 +1106,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1131,109 +1131,109 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(14 rows)
SELECT * FROM sales_west;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(4 rows)
SELECT * FROM sales_east;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
(2 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 | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_central;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -1244,7 +1244,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
@@ -1267,42 +1267,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(8 rows)
DROP TABLE sales_range;
@@ -1311,7 +1311,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1334,42 +1334,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
(8 rows)
DROP TABLE sales_range;
@@ -1377,7 +1377,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1399,56 +1399,56 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_others DEFAULT);
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
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-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
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
(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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(4 rows)
DROP TABLE sales_range;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 5a69425d96e..085c422d540 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -14,13 +14,13 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -56,7 +56,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -115,7 +115,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -158,7 +158,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -169,15 +169,15 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -187,8 +187,8 @@ 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -200,14 +200,14 @@ 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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_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);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -216,80 +216,80 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_20 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (30, 'Ford');
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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));
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_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');
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_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 salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_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);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_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');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-select * from salesmans;
-select * from salesmans01_10;
-select * from salesmans10_40;
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -336,8 +336,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -373,14 +373,14 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
@@ -389,20 +389,20 @@ CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi'
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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)
@@ -427,7 +427,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
RESET enable_seqscan;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b4430133522..3a7f2f9c294 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -14,7 +14,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -109,7 +109,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -146,7 +146,7 @@ DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -188,7 +188,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -198,15 +198,15 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1)
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -217,8 +217,8 @@ ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -234,7 +234,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -285,7 +285,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
@@ -335,7 +335,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
@@ -350,11 +350,11 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
sales_date DATE) PARTITION BY RANGE (sales_date);
@@ -376,28 +376,28 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
@@ -408,36 +408,36 @@ INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition of partitioned table with triggers
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -446,125 +446,125 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
-SELECT * FROM salesmans2_3;
-SELECT * FROM salesmans3_4;
-SELECT * FROM salesmans4_5;
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition with deleted columns
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
-select * from salesmans10_20;
-select * from salesmans20_30;
-select * from salesmans30_40;
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
@@ -611,8 +611,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -648,8 +648,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -676,34 +676,34 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
@@ -722,7 +722,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
SET enable_indexscan = ON;
SET enable_seqscan = ON;
@@ -734,7 +734,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -772,7 +772,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -809,7 +809,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
--
2.39.3 (Apple Git-145)
v8-0002-Make-new-partitions-with-parent-s-persistence-dur.patchapplication/octet-stream; name=v8-0002-Make-new-partitions-with-parent-s-persistence-dur.patchDownload
From f10a3a01abbd782d5ae49b4da819c0100490fb90 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:41:09 +0300
Subject: [PATCH v8 2/7] Make new partitions with parent's persistence during
MERGE/SPLIT operations
The createPartitionTable() function is responsible for creating new partitions
for ALTER TABLE ... MERGE PARTITIONS, and ALTER TABLE ... SPLIT PARTITION
commands. It emulates the behaviour of CREATE TABLE ... (LIKE ...), where
new table persistence should be specified by the user. In the table
partitioning persistent of the partition and its parent must match. So, this
commit makes createPartitionTable() copy the persistence of the parent
partition.
Also, this commit makes createPartitionTable() recheck the persistence after
the new table creation. This is needed because persistence might be affected
by pg_temp in search_path.
This commit also changes the signature of createPartitionTable() making it
take the parent's Relation itself instead of the name of the parent relation,
and return the Relation of new partition. That doesn't lead to
complications, because both callers have the parent table open and need to
open the new partition.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/dbc8b96c-3cf0-d1ee-860d-0e491da20485%40gmail.com
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
doc/src/sgml/ref/alter_table.sgml | 21 +++
src/backend/commands/tablecmds.c | 75 ++++++----
src/test/regress/expected/partition_merge.out | 134 +++++++++++++++---
src/test/regress/expected/partition_split.out | 75 +++++++++-
src/test/regress/sql/partition_merge.sql | 88 +++++++++++-
src/test/regress/sql/partition_split.sql | 43 +++++-
6 files changed, 379 insertions(+), 57 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index fe36ff82e52..a793899b69b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1153,6 +1153,17 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
splitting we have a partition with the same name).
Only simple, non-partitioned partition can be split.
</para>
+ <para>
+ Any indexes, constraints and user-defined row-level triggers that exist
+ in the parent table are cloned on new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... .
+ New partitions will have the same column names and types as the
+ partitioned table to which they belong.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
@@ -1213,6 +1224,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
can have the same name as one of the merged partitions. Only simple,
non-partitioned partitions can be merged.
</para>
+ <para>
+ Any indexes, constraints and user-defined row-level triggers that exist
+ in the parent table are cloned on the new partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ The new partition will have the same column names and types as the
+ partitioned table to which it belongs.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dbb6ee356bb..1b89e18eb7e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21183,18 +21183,30 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* createPartitionTable: create table for a new partition with given name
- * (newPartName) like table (modelRelName)
+ * (newPartName) like table (modelRel)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
@@ -21207,7 +21219,8 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
createStmt->if_not_exists = false;
tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
/*
* Indexes will be inherited on "attach new partitions" stage, after data
@@ -21233,6 +21246,35 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL,
None_Receiver,
NULL);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
}
/*
@@ -21252,7 +21294,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
char tmpRelName[NAMEDATALEN];
List *newPartRels = NIL;
ObjectAddress object;
- RangeVar *parentName;
Oid defaultPartOid;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -21324,18 +21365,12 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create new partitions (like split partition), without indexes. */
- parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1);
foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
+ newPartRel = createPartitionTable(sps->name, rel, context);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21539,18 +21574,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- createPartitionTable(cmd->name,
- makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1),
- context);
-
- /*
- * Open the new partition and acquire exclusive lock on it. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2e0bfdc705d..3aae5f89e80 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -3,6 +3,7 @@
-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
--
CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
SET search_path = partitions_merge_schema, public;
--
-- BY RANGE partitioning
@@ -36,18 +37,23 @@ ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of p
-- (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;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
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
+ oid | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
(4 rows)
DROP TABLE sales_range;
@@ -95,23 +101,24 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
sales_others | r | f | DEFAULT
(5 rows)
-ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+ oid | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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)
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
(1 row)
SELECT * FROM sales_range;
@@ -141,7 +148,7 @@ SELECT * FROM sales_jan2022;
13 | Gandi | 377 | 01-09-2022
(3 rows)
-SELECT * FROM sales_feb_mar_apr2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
2 | Smirnoff | 500 | 02-10-2022
@@ -164,7 +171,7 @@ SELECT * FROM sales_others;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
-SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
2 | Smirnoff | 500 | 02-10-2022
@@ -746,6 +753,34 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
@@ -771,4 +806,63 @@ Not-null constraints:
DROP TABLE t;
--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 419d169f036..e2a362ffafd 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -3,6 +3,7 @@
-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
--
CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
SET search_path = partition_split_schema, public;
--
-- BY RANGE partitioning
@@ -104,6 +105,28 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+---------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesman_id | integer | | | | plain | |
+ salesman_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
DROP TABLE sales_range;
DROP TABLE sales_others;
--
@@ -197,10 +220,26 @@ CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amou
CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+---------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesman_id | integer | | | | plain | |
+ salesman_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
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');
@@ -250,7 +289,7 @@ SELECT * FROM sales_feb2022;
8 | Ericsson | 185 | 02-23-2022
(3 rows)
-SELECT * FROM sales_mar2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
7 | Li | 175 | 03-08-2022
@@ -1427,4 +1466,34 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 72b1cb0b35e..5a69425d96e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -4,6 +4,7 @@
--
CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
SET search_path = partitions_merge_schema, public;
--
@@ -37,8 +38,13 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sal
-- (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;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
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
@@ -81,7 +87,8 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
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;
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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)
@@ -89,17 +96,17 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
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 pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
SELECT * FROM sales_range;
SELECT * FROM sales_jan2022;
-SELECT * FROM sales_feb_mar_apr2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
SELECT * FROM sales_others;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
-SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
RESET enable_seqscan;
@@ -444,6 +451,28 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
@@ -462,5 +491,52 @@ ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b63532ee562..b4430133522 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -4,6 +4,7 @@
--
CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
SET search_path = partition_split_schema, public;
--
@@ -92,6 +93,16 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
DROP TABLE sales_range;
DROP TABLE sales_others;
@@ -140,10 +151,12 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10');
@@ -163,7 +176,7 @@ INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
SELECT * FROM sales_range;
SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb2022;
-SELECT * FROM sales_mar2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
SELECT * FROM sales_apr2022;
SELECT * FROM sales_others;
@@ -844,5 +857,29 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
--
2.39.3 (Apple Git-145)
v8-0005-Add-tab-completion-for-partition-MERGE-SPLIT-oper.patchapplication/octet-stream; name=v8-0005-Add-tab-completion-for-partition-MERGE-SPLIT-oper.patchDownload
From c86c051eb0fd187f82f0c8111421ccb33f9cceb5 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 13:20:11 +0300
Subject: [PATCH v8 5/7] Add tab completion for partition MERGE/SPLIT
operations
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
This commit implements psql tab completion for ALTER TABLE ... SPLIT PARTITION
and ALTER TABLE ... MERGE PARTITIONS commands.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/5dee3937-8e9f-cca4-11fb-737709a92b37%40gmail.com
Author: Dagfinn Ilmari Mannsåker
---
src/bin/psql/tab-complete.c | 18 ++++++++++++++++--
1 file changed, 16 insertions(+), 2 deletions(-)
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 6fee3160f02..97cd5d9f628 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2609,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2620,6 +2621,19 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
--
2.39.3 (Apple Git-145)
v8-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchapplication/octet-stream; name=v8-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchDownload
From f17c461ea4e054950ee4e4f423ea223d20382477 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 19 Apr 2024 13:39:45 +0300
Subject: [PATCH v8 1/7] Change the way ATExecMergePartitions() handles the
name collision
The name collision happens when the name of the new partition is the same as
the name of one of the merging partitions. Currently, ATExecMergePartitions()
first gives the new partition a temporary name and then renames it when old
partitions are deleted. That negatively influences the naming of related
objects like indexes and constrains, which could inherit a temporary name.
This commit changes the implementation in the following way. A merging
partition gets renamed first, then the new partition is created with the
right name immediately. This resolves the issue of the naming of related
objects.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/edfbd846-dcc1-42d1-ac26-715691b687d3%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas
---
src/backend/commands/tablecmds.c | 63 +++++++++----------
src/test/regress/expected/partition_merge.out | 25 ++++++++
src/test/regress/sql/partition_merge.sql | 18 ++++++
3 files changed, 73 insertions(+), 33 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3556240c8ed..dbb6ee356bb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21477,9 +21477,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
- char tmpRelName[NAMEDATALEN];
- RangeVar *mergePartName = cmd->name;
- bool isSameName = false;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -21501,8 +21498,28 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* function transformPartitionCmdForMerge().
*/
if (equal(name, cmd->name))
+ {
/* One new partition can have the same name as merged partition. */
- isSameName = true;
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(mergingPartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
/* Store a next merging partition into the list. */
mergingPartitionsList = lappend(mergingPartitionsList,
@@ -21522,15 +21539,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- /* Create table for new partition, use partitioned table as model. */
- if (isSameName)
- {
- /* Create partition table with generated temporary name. */
- sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- tmpRelName, -1);
- }
- createPartitionTable(mergePartName,
+ createPartitionTable(cmd->name,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21541,18 +21550,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* excessive, but this is the way we make sure nobody is planning queries
* involving merging partitions.
*/
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the partitioned table. wqueue = NULL:
- * verification for each cloned constraint is not need.
- */
- attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
-
- /* Unlock and drop merged partitions. */
+ /* Drop the current partitions before attaching the new one. */
foreach(listptr, mergingPartitionsList)
{
ObjectAddress object;
@@ -21570,18 +21573,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
list_free(mergingPartitionsList);
- /* 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);
- }
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 373d32948ca..2e0bfdc705d 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,4 +746,29 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "tp_1_2_i_not_null" NOT NULL "i"
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 6a0b35b1799..72b1cb0b35e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,5 +444,23 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
--
2.39.3 (Apple Git-145)
v8-0006-Inherit-parent-s-AM-for-partition-MERGE-SPLIT-ope.patchapplication/octet-stream; name=v8-0006-Inherit-parent-s-AM-for-partition-MERGE-SPLIT-ope.patchDownload
From 5fc0bcb59f1f40a2d10dd191d208b074145bd4c4 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 13:21:14 +0300
Subject: [PATCH v8 6/7] Inherit parent's AM for partition MERGE/SPLIT
operations
This commit makes new partitions created by ALTER TABLE ... SPLIT PARTITION
and ALTER TABLE ... MERGE PARTITIONS commands inherit the paret table access
method.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/84ada05b-be5c-473e-6d1c-ebe5dd21b190%40gmail.com
---
doc/src/sgml/ref/alter_table.sgml | 8 +++----
src/backend/commands/tablecmds.c | 6 +++++
src/test/regress/expected/partition_merge.out | 18 +++++++++++++++
src/test/regress/expected/partition_split.out | 23 +++++++++++++++++--
src/test/regress/sql/partition_merge.sql | 13 +++++++++++
src/test/regress/sql/partition_split.sql | 14 +++++++++++
6 files changed, 76 insertions(+), 6 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index a793899b69b..dba49a7ac8f 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1158,8 +1158,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
in the parent table are cloned on new partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... .
- New partitions will have the same column names and types as the
- partitioned table to which they belong.
+ New partitions will have the same table access method,
+ same column names and types as the partitioned table to which they belong.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
are also created temporary.
@@ -1228,8 +1228,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
Any indexes, constraints and user-defined row-level triggers that exist
in the parent table are cloned on the new partition
<replaceable class="parameter">partition_name</replaceable>.
- The new partition will have the same column names and types as the
- partitioned table to which it belongs.
+ The new partition will have the same table access method,
+ same column names and types as the partitioned table to which it belongs.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
is also created temporary.
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1b89e18eb7e..fd0812cd649 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21187,6 +21187,11 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
@@ -21217,6 +21222,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
createStmt->oncommit = ONCOMMIT_NOOP;
createStmt->tablespacename = NULL;
createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
tlc = makeNode(TableLikeClause);
tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index a92a270c591..92999703217 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -862,6 +862,24 @@ SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ROLLBACK;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass);
+ relname | amname
+---------+-----------------------
+ tp_0_2 | partitions_merge_heap
+ t | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 55ae37ad370..326fa1bd400 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -85,8 +85,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
- ^
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -1494,6 +1494,25 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
(2 rows)
DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass);
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 085c422d540..23795cf9d94 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -535,6 +535,19 @@ SET search_path = partitions_merge_schema, pg_temp, public;
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ROLLBACK;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass);
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
RESET search_path;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 3a7f2f9c294..73e8c2fbeb9 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -880,6 +880,20 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass);
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
--
2.39.3 (Apple Git-145)
v8-0007-Grammar-fixes-for-documentation-of-partition-MERG.patchapplication/octet-stream; name=v8-0007-Grammar-fixes-for-documentation-of-partition-MERG.patchDownload
From 146d6946d7ff58dda8c32e048d9b8cf30c8278de Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 13:18:31 +0300
Subject: [PATCH v8 7/7] Grammar fixes for documentation of partition
MERGE/SPLIT operations
Discussion: https://postgr.es/m/ZiGH0xc1lxJ71ZfB%40pryzbyj2023
Author: Justin Pryzby
---
doc/src/sgml/ddl.sgml | 4 ++--
doc/src/sgml/ref/alter_table.sgml | 22 +++++++++++-----------
2 files changed, 13 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 026bfff70f3..01277b1d327 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4384,7 +4384,7 @@ ALTER INDEX measurement_city_id_logdate_key
<para>
There is also an option for merging multiple table partitions into
- a single partition using the
+ a single partition using
<link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
This feature simplifies the management of partitioned tables by allowing
users to combine partitions that are no longer needed as
@@ -4403,7 +4403,7 @@ ALTER TABLE measurement
<para>
Similarly to merging multiple table partitions, there is an option for
- splitting a single partition into multiple using the
+ splitting a single partition into multiple partitions using
<link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
This feature could come in handy when one partition grows too big
and needs to be split into multiple. It's important to note that
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index dba49a7ac8f..db477856395 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1136,16 +1136,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
In case one of the new partitions or one of existing partitions is DEFAULT,
new partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have gaps
between partitions bounds. If the partitioned table does not have a DEFAULT
partition, the DEFAULT partition can be defined as one of the new partitions.
</para>
<para>
In case new partitions do not contain a DEFAULT partition and the partitioned table
- does not have a DEFAULT partition, the following must be true: sum bounds of
+ does not have a DEFAULT partition, the following must be true: the sum bounds of
new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... should be
- equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ equal to the bounds of split partition <replaceable class="parameter">partition_name</replaceable>.
One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable>, ... can have
the same name as split partition <replaceable class="parameter">partition_name</replaceable>
@@ -1179,24 +1179,24 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
- This form merges several partitions into the one partition of the target table.
- Hash-partitioning is not supported. If DEFAULT partition is not in the
+ This form merges several partitions of the target table into a single partition.
+ Hash-partitioning is not supported. If a DEFAULT partition is not in the
list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables it is necessary that the ranges
+ For range-partitioned tables, it is necessary that the ranges
of the partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] can
- be merged into one range without spaces and overlaps (otherwise an error
+ be merged into one range with neither gaps nor overlaps (otherwise an error
will be generated). The combined range will be the range for the partition
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
<listitem>
<para>
- For list-partitioned tables the value lists of all partitions
+ For list-partitioned tables, the value lists of all partitions
<replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...] are
combined and form the list of values of partition
@@ -1204,7 +1204,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
</listitem>
</itemizedlist>
- If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ If a DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
@@ -1215,8 +1215,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- For range- and list-partitioned tables the ranges and lists of values
- of the merged partitions can be any.
+ For range- and list-partitioned tables, the ranges and lists of values
+ of the merged partitions can be anything.
</para>
</listitem>
</itemizedlist>
--
2.39.3 (Apple Git-145)
On Mon, Apr 22, 2024 at 01:31:48PM +0300, Alexander Korotkov wrote:
Hi!
On Fri, Apr 19, 2024 at 4:29 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, Apr 19, 2024 at 2:26 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patchI've incorporated this fix with 0001 patch.
Also added to the patchset
005 – tab completion by Dagfinn [1]
006 – draft fix for table AM issue spotted by Alexander Lakhin [2]
007 – doc review by Justin [3]I'm continuing work on this.
Links
1. /messages/by-id/87plumiox2.fsf@wibble.ilmari.org
2. /messages/by-id/84ada05b-be5c-473e-6d1c-ebe5dd21b190@gmail.com
3. /messages/by-id/ZiGH0xc1lxJ71ZfB@pryzbyj20230001
The way we handle name collisions during MERGE PARTITIONS operation is
reworked by integration of patch [3]. This makes note about commit in
[2] not relevant.
This patch also/already fixes the schema issue I reported. Thanks.
If you wanted to include a test case for that:
begin;
CREATE SCHEMA s;
CREATE SCHEMA t;
CREATE TABLE p(i int) PARTITION BY RANGE(i);
CREATE TABLE s.c1 PARTITION OF p FOR VALUES FROM (1)TO(2);
CREATE TABLE s.c2 PARTITION OF p FOR VALUES FROM (2)TO(3);
ALTER TABLE p MERGE PARTITIONS (s.c1, s.c2) INTO s.c1; -- misbehaves if merging into the same name as an existing partition
\d+ p
...
Partitions: c1 FOR VALUES FROM (1) TO (3)
0002
The persistence of the new partition is copied as suggested in [1].
But the checks are in-place, because search_path could influence new
table persistence. Per review [2], commit message typos are fixed,
documentation is revised, revised tests to cover schema-qualification,
usage of search_path.
Subject: [PATCH v8 2/7] Make new partitions with parent's persistence during MERGE/SPLIT operations
This patch adds documentation saying:
+ Any indexes, constraints and user-defined row-level triggers that exist
+ in the parent table are cloned on new partitions [...]
Which is good to say, and addresses part of my message [0]ZiJW1g2nbQs9ekwK@pryzbyj2023
[0]: ZiJW1g2nbQs9ekwK@pryzbyj2023
But it doesn't have anything to do with "creating new partitions with
parent's persistence". Maybe there was a merge conflict and the docs
ended up in the wrong patch ?
Also, defaults, storage options, compression are also copied. As will
be anything else from LIKE. And since anything added in the future will
also be copied, maybe it's better to just say that the tables will be
created the same way as "LIKE .. INCLUDING ALL EXCLUDING ..", or
similar. Otherwise, the next person who adds a new option for LIKE
would have to remember to update this paragraph...
Also, extended stats objects are currently cloned to new child tables.
But I suggested in [0]ZiJW1g2nbQs9ekwK@pryzbyj2023 that they probably shouldn't be.
007 – doc review by Justin [3]
I suggest to drop this patch for now. I'll send some more minor fixes to
docs and code comments once the other patches are settled.
--
Justin
Hi, Hackers!
On Thu, 25 Apr 2024 at 00:26, Justin Pryzby <pryzby@telsasoft.com> wrote:
On Mon, Apr 22, 2024 at 01:31:48PM +0300, Alexander Korotkov wrote:
Hi!
On Fri, Apr 19, 2024 at 4:29 PM Alexander Korotkov <aekorotkov@gmail.com>
wrote:
On Fri, Apr 19, 2024 at 2:26 AM Dmitry Koval <d.koval@postgrespro.ru>
wrote:
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patchI've incorporated this fix with 0001 patch.
Also added to the patchset
005 – tab completion by Dagfinn [1]
006 – draft fix for table AM issue spotted by Alexander Lakhin [2]
007 – doc review by Justin [3]I'm continuing work on this.
Links
1./messages/by-id/87plumiox2.fsf@wibble.ilmari.org
2.
/messages/by-id/84ada05b-be5c-473e-6d1c-ebe5dd21b190@gmail.com
3.
/messages/by-id/ZiGH0xc1lxJ71ZfB@pryzbyj2023
0001
The way we handle name collisions during MERGE PARTITIONS operation is
reworked by integration of patch [3]. This makes note about commit in
[2] not relevant.This patch also/already fixes the schema issue I reported. Thanks.
If you wanted to include a test case for that:
begin;
CREATE SCHEMA s;
CREATE SCHEMA t;
CREATE TABLE p(i int) PARTITION BY RANGE(i);
CREATE TABLE s.c1 PARTITION OF p FOR VALUES FROM (1)TO(2);
CREATE TABLE s.c2 PARTITION OF p FOR VALUES FROM (2)TO(3);
ALTER TABLE p MERGE PARTITIONS (s.c1, s.c2) INTO s.c1; -- misbehaves if
merging into the same name as an existing partition
\d+ p
...
Partitions: c1 FOR VALUES FROM (1) TO (3)0002
The persistence of the new partition is copied as suggested in [1].
But the checks are in-place, because search_path could influence new
table persistence. Per review [2], commit message typos are fixed,
documentation is revised, revised tests to cover schema-qualification,
usage of search_path.Subject: [PATCH v8 2/7] Make new partitions with parent's persistence
during MERGE/SPLIT operationsThis patch adds documentation saying: + Any indexes, constraints and user-defined row-level triggers that exist + in the parent table are cloned on new partitions [...]Which is good to say, and addresses part of my message [0]
[0] ZiJW1g2nbQs9ekwK@pryzbyj2023But it doesn't have anything to do with "creating new partitions with
parent's persistence". Maybe there was a merge conflict and the docs
ended up in the wrong patch ?Also, defaults, storage options, compression are also copied. As will
be anything else from LIKE. And since anything added in the future will
also be copied, maybe it's better to just say that the tables will be
created the same way as "LIKE .. INCLUDING ALL EXCLUDING ..", or
similar. Otherwise, the next person who adds a new option for LIKE
would have to remember to update this paragraph...Also, extended stats objects are currently cloned to new child tables.
But I suggested in [0] that they probably shouldn't be.007 – doc review by Justin [3]
I suggest to drop this patch for now. I'll send some more minor fixes to
docs and code comments once the other patches are settled.
I've looked at the patchset:
0001 Look good.
0002 Also right with docs modification proposed by Justin.
0003:
Looks like unused code
5268 datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) -
1) : NULL;
overridden by
5278 datum = list_nth(spec->upperdatums, abs(cmpval) -
1);
and
5290 datum = list_nth(spec->upperdatums, abs(cmpval) -
1);
Otherwise - good.
0004:
I suggest also getting rid of thee-noun compound words like:
salesperson_name. Maybe salesperson -> clerk? Or maybe use the same terms
like in pgbench: branches, tellers, accounts, balance.
0005: Good
0006: Patch is right
In comments:
+ New partitions will have the same table access method,
+ same column names and types as the partitioned table to which they
belong.
(I'd suggest to remove second "same")
Tests are passed. I suppose that it's better to add similar tests for
SPLIT/MERGE PARTITION(S) to those covering ATTACH/DETACH PARTITION (e.g.:
subscription/t/013_partition.pl and regression tests)
Overall, great work! Thanks!
Regards,
Pavel Borisov,
Supabase.
Hi, Pavel.
Thank you for the review.
On Fri, Apr 26, 2024 at 4:33 PM Pavel Borisov <pashkin.elfe@gmail.com> wrote:
I've looked at the patchset:
0001 Look good.
0002 Also right with docs modification proposed by Justin.
Modified as proposed by Justin. The documentation for the way new
partitions are created is now in separate patch.
0003:
Looks like unused code
5268 datum = cmpval ? list_nth(spec->lowerdatums, abs(cmpval) - 1) : NULL;
overridden by
5278 datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
and
5290 datum = list_nth(spec->upperdatums, abs(cmpval) - 1);Otherwise - good.
Fixed, thanks.
0004:
I suggest also getting rid of thee-noun compound words like: salesperson_name. Maybe salesperson -> clerk? Or maybe use the same terms like in pgbench: branches, tellers, accounts, balance.
Thank you, but I'd like to prefer keeping these modifications simple.
It's just regression tests, we don't need to have perfect naming here.
My intention is to fix just obvious errors.
0005: Good 0006: Patch is right In comments: + New partitions will have the same table access method, + same column names and types as the partitioned table to which they belong. (I'd suggest to remove second "same")
Documentation is modified per proposal by Justin. Thus double "same"
is already gone.
Tests are passed. I suppose that it's better to add similar tests for SPLIT/MERGE PARTITION(S) to those covering ATTACH/DETACH PARTITION (e.g.: subscription/t/013_partition.pl and regression tests)
The revised patchset is attached. I'm going to push it if there are
no objections.
Thank you for your suggestions about adding tests similar to
subscription/t/013_partition.pl. I will work on this after pushing
this patchset.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v9-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchapplication/octet-stream; name=v9-0001-Change-the-way-ATExecMergePartitions-handles-the-.patchDownload
From a6d5687a942e8f8f1f6863f9b76c009a97130d03 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 19 Apr 2024 13:39:45 +0300
Subject: [PATCH v9 1/7] Change the way ATExecMergePartitions() handles the
name collision
The name collision happens when the name of the new partition is the same as
the name of one of the merging partitions. Currently, ATExecMergePartitions()
first gives the new partition a temporary name and then renames it when old
partitions are deleted. That negatively influences the naming of related
objects like indexes and constrains, which could inherit a temporary name.
This commit changes the implementation in the following way. A merging
partition gets renamed first, then the new partition is created with the
right name immediately. This resolves the issue of the naming of related
objects.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/edfbd846-dcc1-42d1-ac26-715691b687d3%40postgrespro.ru
Author: Dmitry Koval, Alexander Korotkov
Reviewed-by: Robert Haas, Justin Pryzby, Pavel Borisov
---
src/backend/commands/tablecmds.c | 63 +++++++++----------
src/test/regress/expected/partition_merge.out | 25 ++++++++
src/test/regress/sql/partition_merge.sql | 18 ++++++
3 files changed, 73 insertions(+), 33 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3556240c8ed..dbb6ee356bb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21477,9 +21477,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
- char tmpRelName[NAMEDATALEN];
- RangeVar *mergePartName = cmd->name;
- bool isSameName = false;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -21501,8 +21498,28 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* function transformPartitionCmdForMerge().
*/
if (equal(name, cmd->name))
+ {
/* One new partition can have the same name as merged partition. */
- isSameName = true;
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(mergingPartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
/* Store a next merging partition into the list. */
mergingPartitionsList = lappend(mergingPartitionsList,
@@ -21522,15 +21539,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- /* Create table for new partition, use partitioned table as model. */
- if (isSameName)
- {
- /* Create partition table with generated temporary name. */
- sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
- mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- tmpRelName, -1);
- }
- createPartitionTable(mergePartName,
+ createPartitionTable(cmd->name,
makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
RelationGetRelationName(rel), -1),
context);
@@ -21541,18 +21550,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* excessive, but this is the way we make sure nobody is planning queries
* involving merging partitions.
*/
- newPartRel = table_openrv(mergePartName, AccessExclusiveLock);
+ newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
- /*
- * Attach a new partition to the partitioned table. wqueue = NULL:
- * verification for each cloned constraint is not need.
- */
- attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
-
- /* Unlock and drop merged partitions. */
+ /* Drop the current partitions before attaching the new one. */
foreach(listptr, mergingPartitionsList)
{
ObjectAddress object;
@@ -21570,18 +21573,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
list_free(mergingPartitionsList);
- /* 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);
- }
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
/* Keep the lock until commit. */
table_close(newPartRel, NoLock);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 373d32948ca..2e0bfdc705d 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -746,4 +746,29 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "tp_1_2_i_not_null" NOT NULL "i"
+
+DROP TABLE t;
+--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 6a0b35b1799..72b1cb0b35e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -444,5 +444,23 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
--
DROP SCHEMA partitions_merge_schema;
--
2.39.3 (Apple Git-145)
v9-0003-Make-new-partitions-with-parent-s-persistence-dur.patchapplication/octet-stream; name=v9-0003-Make-new-partitions-with-parent-s-persistence-dur.patchDownload
From f69c80850a8bd8e79313ca8c4ccff9a49c53615f Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:41:09 +0300
Subject: [PATCH v9 3/7] Make new partitions with parent's persistence during
MERGE/SPLIT operations
The createPartitionTable() function is responsible for creating new partitions
for ALTER TABLE ... MERGE PARTITIONS, and ALTER TABLE ... SPLIT PARTITION
commands. It emulates the behaviour of CREATE TABLE ... (LIKE ...), where
new table persistence should be specified by the user. In the table
partitioning persistent of the partition and its parent must match. So, this
commit makes createPartitionTable() copy the persistence of the parent
partition.
Also, this commit makes createPartitionTable() recheck the persistence after
the new table creation. This is needed because persistence might be affected
by pg_temp in search_path.
This commit also changes the signature of createPartitionTable() making it
take the parent's Relation itself instead of the name of the parent relation,
and return the Relation of new partition. That doesn't lead to
complications, because both callers have the parent table open and need to
open the new partition.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/dbc8b96c-3cf0-d1ee-860d-0e491da20485%40gmail.com
Author: Dmitry Koval
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
---
doc/src/sgml/ref/alter_table.sgml | 6 +
src/backend/commands/tablecmds.c | 75 ++++++----
src/test/regress/expected/partition_merge.out | 134 +++++++++++++++---
src/test/regress/expected/partition_split.out | 75 +++++++++-
src/test/regress/sql/partition_merge.sql | 88 +++++++++++-
src/test/regress/sql/partition_split.sql | 43 +++++-
6 files changed, 364 insertions(+), 57 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8a10a8bd79b..0f546357863 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1158,6 +1158,9 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name1</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
The indexes and identity are created later after moving the data
while attaching new partitions.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary.
</para>
<note>
<para>
@@ -1224,6 +1227,9 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
The indexes and identity are created later after moving the data
while attaching the new partition.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary.
</para>
<note>
<para>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dbb6ee356bb..1b89e18eb7e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21183,18 +21183,30 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
/*
* createPartitionTable: create table for a new partition with given name
- * (newPartName) like table (modelRelName)
+ * (newPartName) like table (modelRel)
*
- * Emulates command: CREATE TABLE <newPartName> (LIKE <modelRelName>
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
*/
-static void
-createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
AlterTableUtilityContext *context)
{
CreateStmt *createStmt;
TableLikeClause *tlc;
PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
createStmt = makeNode(CreateStmt);
createStmt->relation = newPartName;
@@ -21207,7 +21219,8 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
createStmt->if_not_exists = false;
tlc = makeNode(TableLikeClause);
- tlc->relation = modelRelName;
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
/*
* Indexes will be inherited on "attach new partitions" stage, after data
@@ -21233,6 +21246,35 @@ createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName,
NULL,
None_Receiver,
NULL);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
}
/*
@@ -21252,7 +21294,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
char tmpRelName[NAMEDATALEN];
List *newPartRels = NIL;
ObjectAddress object;
- RangeVar *parentName;
Oid defaultPartOid;
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
@@ -21324,18 +21365,12 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create new partitions (like split partition), without indexes. */
- parentName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1);
foreach(listptr, cmd->partlist)
{
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- createPartitionTable(sps->name, parentName, context);
-
- /* Open the new partition and acquire exclusive lock on it. */
- newPartRel = table_openrv(sps->name, AccessExclusiveLock);
-
+ newPartRel = createPartitionTable(sps->name, rel, context);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21539,18 +21574,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
- createPartitionTable(cmd->name,
- makeRangeVar(get_namespace_name(RelationGetNamespace(rel)),
- RelationGetRelationName(rel), -1),
- context);
-
- /*
- * Open the new partition and acquire exclusive lock on it. This will
- * stop all the operations with partitioned table. This might seem
- * excessive, but this is the way we make sure nobody is planning queries
- * involving merging partitions.
- */
- newPartRel = table_openrv(cmd->name, AccessExclusiveLock);
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 2e0bfdc705d..3aae5f89e80 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -3,6 +3,7 @@
-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
--
CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
SET search_path = partitions_merge_schema, public;
--
-- BY RANGE partitioning
@@ -36,18 +37,23 @@ ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of p
-- (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;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
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
+ oid | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
(4 rows)
DROP TABLE sales_range;
@@ -95,23 +101,24 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
sales_others | r | f | DEFAULT
(5 rows)
-ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+ oid | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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)
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
(1 row)
SELECT * FROM sales_range;
@@ -141,7 +148,7 @@ SELECT * FROM sales_jan2022;
13 | Gandi | 377 | 01-09-2022
(3 rows)
-SELECT * FROM sales_feb_mar_apr2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
2 | Smirnoff | 500 | 02-10-2022
@@ -164,7 +171,7 @@ SELECT * FROM sales_others;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
-SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
2 | Smirnoff | 500 | 02-10-2022
@@ -746,6 +753,34 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
@@ -771,4 +806,63 @@ Not-null constraints:
DROP TABLE t;
--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+RESET search_path;
+--
DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 419d169f036..e2a362ffafd 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -3,6 +3,7 @@
-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
--
CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
SET search_path = partition_split_schema, public;
--
-- BY RANGE partitioning
@@ -104,6 +105,28 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+---------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesman_id | integer | | | | plain | |
+ salesman_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
DROP TABLE sales_range;
DROP TABLE sales_others;
--
@@ -197,10 +220,26 @@ CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amou
CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+---------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesman_id | integer | | | | plain | |
+ salesman_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
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');
@@ -250,7 +289,7 @@ SELECT * FROM sales_feb2022;
8 | Ericsson | 185 | 02-23-2022
(3 rows)
-SELECT * FROM sales_mar2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
salesman_id | salesman_name | sales_amount | sales_date
-------------+---------------+--------------+------------
7 | Li | 175 | 03-08-2022
@@ -1427,4 +1466,34 @@ ERROR: relation "t1pa" is not a partition of relation "t2"
DROP TABLE t2;
DROP TABLE t1;
--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+--
DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 72b1cb0b35e..5a69425d96e 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -4,6 +4,7 @@
--
CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
SET search_path = partitions_merge_schema, public;
--
@@ -37,8 +38,13 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sal
-- (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;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
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
@@ -81,7 +87,8 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
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;
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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)
@@ -89,17 +96,17 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
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 pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
SELECT * FROM sales_range;
SELECT * FROM sales_jan2022;
-SELECT * FROM sales_feb_mar_apr2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
SELECT * FROM sales_others;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
-SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
RESET enable_seqscan;
@@ -444,6 +451,28 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
@@ -462,5 +491,52 @@ ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+RESET search_path;
+
--
DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b63532ee562..b4430133522 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -4,6 +4,7 @@
--
CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
SET search_path = partition_split_schema, public;
--
@@ -92,6 +93,16 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
DROP TABLE sales_range;
DROP TABLE sales_others;
@@ -140,10 +151,12 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10');
@@ -163,7 +176,7 @@ INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
SELECT * FROM sales_range;
SELECT * FROM sales_jan2022;
SELECT * FROM sales_feb2022;
-SELECT * FROM sales_mar2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
SELECT * FROM sales_apr2022;
SELECT * FROM sales_others;
@@ -844,5 +857,29 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
DROP TABLE t2;
DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
--
2.39.3 (Apple Git-145)
v9-0004-Fix-error-message-in-check_partition_bounds_for_s.patchapplication/octet-stream; name=v9-0004-Fix-error-message-in-check_partition_bounds_for_s.patchDownload
From dbf49badfd1f0556958f212f8bf53cbfd46998a7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Thu, 18 Apr 2024 12:56:51 +0300
Subject: [PATCH v9 4/7] Fix error message in
check_partition_bounds_for_split_range()
Currently, the error message is produced by a system of complex substitutions
making it quite untranslatable and hard to read. This commit splits this into
4 plain error messages suitable for translation.
Reported-by: Kyotaro Horiguchi
Discussion: https://postgr.es/m/20240408.152402.1485994009160660141.horikyota.ntt%40gmail.com
Reviewed-by: Pavel Borisov
---
src/backend/partitioning/partbounds.c | 70 +++++++++++++++++++--------
1 file changed, 49 insertions(+), 21 deletions(-)
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b08edf87a69..4eda59767ce 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5211,7 +5211,7 @@ check_partition_bounds_for_split_range(Relation parent,
if (first || last)
{
PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
- bool overlap = false;
+ PartitionRangeDatum *datum;
if (first)
{
@@ -5229,8 +5229,30 @@ check_partition_bounds_for_split_range(Relation parent,
* Lower bound of "spec" should be equal (or greater than or equal
* in case defaultPart=true) to lower bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
- overlap = true;
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
}
else
{
@@ -5248,24 +5270,30 @@ check_partition_bounds_for_split_range(Relation parent,
* Upper bound of "spec" should be equal (or less than or equal in
* case defaultPart=true) to upper bound of split partition.
*/
- if ((!defaultPart && cmpval) || (defaultPart && cmpval > 0))
- overlap = true;
- }
-
- if (overlap)
- {
- PartitionRangeDatum *datum;
-
- datum = list_nth(first ? spec->lowerdatums : spec->upperdatums, abs(cmpval) - 1);
-
- ereport(ERROR,
- (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("%s bound of partition \"%s\" is %s %s bound of split partition",
- first ? "lower" : "upper",
- relname,
- defaultPart ? (first ? "less than" : "greater than") : "not equal to",
- first ? "lower" : "upper"),
- parser_errposition(pstate, datum->location)));
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
}
}
}
--
2.39.3 (Apple Git-145)
v9-0002-Document-the-way-parition-MERGE-SPLIT-operations-.patchapplication/octet-stream; name=v9-0002-Document-the-way-parition-MERGE-SPLIT-operations-.patchDownload
From 337fe9ee0288df424ac15cef3e68fba096525af7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 28 Apr 2024 03:39:30 +0300
Subject: [PATCH v9 2/7] Document the way parition MERGE/SPLIT operations
create new partitions
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZilrByTp-pbz6Mvf%40pryzbyj2023
---
doc/src/sgml/ref/alter_table.sgml | 12 ++++++++++++
1 file changed, 12 insertions(+)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index fe36ff82e52..8a10a8bd79b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1153,6 +1153,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
splitting we have a partition with the same name).
Only simple, non-partitioned partition can be split.
</para>
+ <para>
+ New partitions are created the same way as they get created with an
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name1</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ The indexes and identity are created later after moving the data
+ while attaching new partitions.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
@@ -1213,6 +1219,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
can have the same name as one of the merged partitions. Only simple,
non-partitioned partitions can be merged.
</para>
+ <para>
+ The new partition are created the same way as it gets created with an
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ The indexes and identity are created later after moving the data
+ while attaching the new partition.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
--
2.39.3 (Apple Git-145)
v9-0005-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchapplication/octet-stream; name=v9-0005-Rename-tables-in-tests-of-partition-MERGE-SPLIT-o.patchDownload
From 4dab981213713687849edab924e45211904fab89 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 11:31:57 +0300
Subject: [PATCH v9 5/7] Rename tables in tests of partition MERGE/SPLIT
operations
Replace "salesman" with "salesperson", "salesmen" with "salespeople". The
names are both gramatically correct and gender-neutral.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/fdaa003e-919c-cbc9-4f0c-e4546e96bd65%40gmail.com
Reviewed-by: Robert Haas, Pavel Borisov
---
src/test/regress/expected/partition_merge.out | 666 ++++-----
src/test/regress/expected/partition_split.out | 1266 ++++++++---------
src/test/regress/sql/partition_merge.sql | 160 +--
src/test/regress/sql/partition_split.sql | 280 ++--
4 files changed, 1186 insertions(+), 1186 deletions(-)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 3aae5f89e80..a92a270c591 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -11,12 +11,12 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -60,7 +60,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -122,68 +122,68 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemanam
(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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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 partitions_merge_schema2.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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM partitions_merge_schema2.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
+ salesperson_id | salesperson_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)
RESET enable_seqscan;
@@ -191,7 +191,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -216,15 +216,15 @@ INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
-- 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
+ salesperson_id | salesperson_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:
@@ -246,7 +246,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -255,219 +255,219 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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
+ salesperson_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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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;
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) 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
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_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
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
- 20 | Smirnoff
- 31 | Popov
- 30 | Ford
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
(5 rows)
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -489,88 +489,88 @@ 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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;
@@ -581,8 +581,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -614,33 +614,33 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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
@@ -669,68 +669,68 @@ SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_ge
(3 rows)
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 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 | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_all;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(10 rows)
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
RESET enable_seqscan;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index e2a362ffafd..55ae37ad370 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -11,7 +11,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -85,8 +85,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
- ^
+LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -114,13 +114,13 @@ SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
SET search_path = partition_split_schema, public;
\d+ sales_range
- Partitioned table "partition_split_schema.sales_range"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
- salesman_id | integer | | | | plain | |
- salesman_name | character varying(30) | | | | extended | |
- sales_amount | integer | | | | plain | |
- sales_date | date | | | | plain | |
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
Partition key: RANGE (sales_date)
Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
@@ -132,7 +132,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -155,68 +155,68 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -226,13 +226,13 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
\d+ sales_range
- Partitioned table "partition_split_schema.sales_range"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
- salesman_id | integer | | | | plain | |
- salesman_name | character varying(30) | | | | extended | |
- sales_amount | integer | | | | plain | |
- sales_date | date | | | | plain | |
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
Partition key: RANGE (sales_date)
Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
@@ -255,61 +255,61 @@ 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
- 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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM partition_split_schema2.sales_mar2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
DROP TABLE sales_range CASCADE;
@@ -319,7 +319,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -327,103 +327,103 @@ CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month
CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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
+ salesperson_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
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
(4 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
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
- Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
- Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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
+ salesperson_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
- Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
(3 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
- Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
(3 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
+ salesperson_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)
--ERROR: relation "sales_jan_feb2022" does not exist
@@ -435,7 +435,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -454,19 +454,19 @@ 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_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-10-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 6 | Poirot | 150 | 02-11-2022
- 7 | Li | 175 | 03-08-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 11 | Trump | 380 | 04-06-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(11 rows)
SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema';
@@ -484,34 +484,34 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_feb2022 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
(3 rows)
SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 11 | Trump | 380 | 04-06-2022
- 5 | Deev | 250 | 04-07-2022
- 4 | Ivanov | 750 | 04-13-2022
- 3 | Ford | 2000 | 04-30-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
(4 rows)
SELECT * FROM sales_others where sales_date > '2022-01-01';
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -544,7 +544,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
@@ -601,7 +601,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -613,20 +613,20 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -635,50 +635,50 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid;
- pg_get_constraintdef | conname | conkey
--------------------------------------------------------------+--------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
- FOREIGN KEY (salesman_id) REFERENCES salesmans(salesman_id) | sales_range_salesman_id_fkey | {1}
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
(2 rows)
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
DETAIL: Failing row contains (1, 0, 03-11-2022).
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(-1) is not present in table "salesmans".
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
INSERT INTO sales VALUES (10, 150, '2022-03-01');
@@ -687,280 +687,280 @@ INSERT INTO sales VALUES (19, 200, '2022-03-04');
INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_40;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
- 20 | Smirnoff
- 30 | Ford
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
(4 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
-DETAIL: Key (salesman_id)=(40) is not present in table "salesmans".
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 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
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (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
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
-NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW
-SELECT * FROM salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 10 | May
- 19 | Ivanov
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
(2 rows)
-SELECT * FROM salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-SELECT * FROM salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-SELECT * FROM salesmans2_3;
- salesman_id | salesman_name
--------------+---------------
- 2 | Ivanov
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
(1 row)
-SELECT * FROM salesmans3_4;
- salesman_id | salesman_name
--------------+---------------
- 3 | May
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
(1 row)
-SELECT * FROM salesmans4_5;
- salesman_id | salesman_name
--------------+---------------
- 4 | Ford
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
(1 row)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
- attname | attidentity | attgenerated
----------------+-------------+--------------
- salesman_id | a |
- salesman_name | |
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
(2 rows)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition 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 TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
- salesman_id | salesman_name
--------------+---------------
- 1 | Poirot
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
(1 row)
-select * from salesmans10_20;
- salesman_id | salesman_name
--------------+---------------
- 19 | Ivanov
- 10 | May
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
(2 rows)
-select * from salesmans20_30;
- salesman_id | salesman_name
--------------+---------------
- 20 | Smirnoff
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
(1 row)
-select * from salesmans30_40;
- salesman_id | salesman_name
--------------+---------------
- 30 | Ford
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
(1 row)
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
@@ -980,31 +980,31 @@ 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
- 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
+ salesperson_id | salesperson_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_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
@@ -1012,50 +1012,50 @@ ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
(1 row)
DROP TABLE sales_range;
@@ -1066,8 +1066,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1106,8 +1106,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -1131,109 +1131,109 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
SELECT * FROM sales_list;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+----------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(14 rows)
SELECT * FROM sales_west;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
(4 rows)
SELECT * FROM sales_east;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
(2 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 | Oslo | 1200 | 03-06-2022
- 9 | May | Oslo | 1200 | 03-11-2022
- 10 | Halder | Helsinki | 800 | 03-02-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
(4 rows)
SELECT * FROM sales_central;
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(4 rows)
-- Use indexscan for testing indexes after splitting partition
SET enable_indexscan = ON;
SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
(2 rows)
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
- salesman_id | salesman_name | sales_state | sales_amount | sales_date
--------------+---------------+-------------+--------------+------------
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 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 | Warsaw | 750 | 03-04-2022
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
(1 row)
SET enable_indexscan = ON;
@@ -1244,7 +1244,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
@@ -1267,42 +1267,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(8 rows)
DROP TABLE sales_range;
@@ -1311,7 +1311,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1334,42 +1334,42 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
SELECT * FROM sales_jan2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 13 | Gandi | 377 | 01-09-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
(1 row)
SELECT * FROM sales_feb2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 2 | Smirnoff | 500 | 02-09-2022
- 6 | Poirot | 150 | 02-07-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
(2 rows)
SELECT * FROM sales_mar2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
(1 row)
SELECT * FROM sales_apr2022_1decade;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(2 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
- 1 | May | 1000 | 01-31-2022
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 8 | Ericsson | 185 | 02-23-2022
- 9 | Muller | 250 | 03-11-2022
- 10 | Halder | 350 | 01-28-2022
- 12 | Plato | 350 | 03-19-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
(8 rows)
DROP TABLE sales_range;
@@ -1377,7 +1377,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -1399,56 +1399,56 @@ ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
PARTITION sales_others DEFAULT);
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
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-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
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
(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
+ salesperson_id | salesperson_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_feb2022;
- 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
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
(3 rows)
SELECT * FROM sales_apr2022;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
(4 rows)
SELECT * FROM sales_others;
- salesman_id | salesman_name | sales_amount | sales_date
--------------+---------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
- 14 | Smith | 510 | 05-04-2022
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
(4 rows)
DROP TABLE sales_range;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 5a69425d96e..085c422d540 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -14,13 +14,13 @@ SET search_path = partitions_merge_schema, public;
--
-- 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_range (salesperson_id INT, salesperson_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_apr2022 (salesperson_id INT, salesperson_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');
@@ -56,7 +56,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -115,7 +115,7 @@ 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_range (salesperson_id INT, salesperson_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');
@@ -158,7 +158,7 @@ DROP TABLE sales_range;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -169,15 +169,15 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -187,8 +187,8 @@ 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -200,14 +200,14 @@ 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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_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);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -216,80 +216,80 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_20 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (30, 'Ford');
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople 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));
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_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');
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_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 salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_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);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_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');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40;
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
-select * from salesmans;
-select * from salesmans01_10;
-select * from salesmans10_40;
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
-DROP TABLE salesmans;
+DROP TABLE salespeople;
--
-- 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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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');
@@ -336,8 +336,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT GENERATED ALWAYS AS IDENTITY,
- salesman_name VARCHAR(30),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -373,14 +373,14 @@ 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),
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
@@ -389,20 +389,20 @@ CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi'
CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 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', 'Helsinki', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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)
@@ -427,7 +427,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
RESET enable_seqscan;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index b4430133522..3a7f2f9c294 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -14,7 +14,7 @@ SET search_path = partition_split_schema, public;
--
-- 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_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -109,7 +109,7 @@ DROP TABLE sales_others;
--
-- Add rows into partitioned table then split 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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -146,7 +146,7 @@ DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
--
-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_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -188,7 +188,7 @@ DROP TABLE sales_range CASCADE;
-- * GENERATED column;
-- * column with DEFAULT value.
--
-CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT,
+CREATE TABLE sales_date (salesperson_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')
@@ -198,15 +198,15 @@ CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1)
CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -217,8 +217,8 @@ ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
(PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
-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);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
SELECT * FROM sales_date;
SELECT * FROM sales_dec2022;
@@ -234,7 +234,7 @@ DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
--
-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_range (salesperson_id INT, salesperson_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_others PARTITION OF sales_range DEFAULT;
CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date);
@@ -285,7 +285,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2022 (lower bound)
@@ -335,7 +335,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
@@ -350,11 +350,11 @@ DROP TABLE sales_range;
--
-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30));
-INSERT INTO salesmans VALUES (1, 'Poirot');
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE TABLE sales_range (
-salesman_id INT REFERENCES salesmans(salesman_id),
+salesperson_id INT REFERENCES salespeople(salesperson_id),
sales_amount INT CHECK (sales_amount > 1),
sales_date DATE) PARTITION BY RANGE (sales_date);
@@ -376,28 +376,28 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conre
-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
--- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesman_id_fkey"
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
-- ok
INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
DROP TABLE sales_range CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
-CREATE TABLE sales (salesman_id INT REFERENCES salesmans(salesman_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (19, 'Ivanov');
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
INSERT INTO sales VALUES (1, 100, '2022-03-01');
INSERT INTO sales VALUES (1, 110, '2022-03-02');
@@ -408,36 +408,36 @@ INSERT INTO sales VALUES (20, 50, '2022-03-12');
INSERT INTO sales VALUES (20, 170, '2022-03-02');
INSERT INTO sales VALUES (30, 30, '2022-03-04');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
--- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesman_id_fkey"
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
INSERT INTO sales VALUES (40, 50, '2022-03-04');
-- ok
INSERT INTO sales VALUES (30, 50, '2022-03-04');
DROP TABLE sales CASCADE;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition of partitioned table with triggers
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
-CREATE TABLE salesmans10_40 PARTITION OF salesmans FOR VALUES FROM (10) TO (40);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (1, 'Poirot');
CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$
BEGIN
@@ -446,125 +446,125 @@ BEGIN
END;
$BODY$;
-CREATE TRIGGER salesmans_after_insert_statement_trigger
+CREATE TRIGGER salespeople_after_insert_statement_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH STATEMENT
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-CREATE TRIGGER salesmans_after_insert_row_trigger
+CREATE TRIGGER salespeople_after_insert_row_trigger
AFTER INSERT
- ON salesmans
+ ON salespeople
FOR EACH ROW
- EXECUTE PROCEDURE after_insert_row_trigger('salesmans');
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (10, 'May');
+INSERT INTO salespeople VALUES (10, 'May');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans10_40 VALUES (19, 'Ivanov');
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-- 2 triggers should fire here (row + statement):
-INSERT INTO salesmans VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
-- 1 trigger should fire here (row):
-INSERT INTO salesmans30_40 VALUES (30, 'Ford');
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
-SELECT * FROM salesmans01_10;
-SELECT * FROM salesmans10_20;
-SELECT * FROM salesmans20_30;
-SELECT * FROM salesmans30_40;
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
DROP FUNCTION after_insert_row_trigger();
--
-- Test: split partition witch identity column
-- If split partition column is identity column, columns of new partitions are identity columns too.
--
-CREATE TABLE salesmans(salesman_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans1_2 PARTITION OF salesmans FOR VALUES FROM (1) TO (2);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
-- Create new partition with identity column:
-CREATE TABLE salesmans2_5(salesman_id INT NOT NULL, salesman_name VARCHAR(30));
-ALTER TABLE salesmans ATTACH PARTITION salesmans2_5 FOR VALUES FROM (2) TO (5);
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
-INSERT INTO salesmans (salesman_name) VALUES ('Poirot');
-INSERT INTO salesmans (salesman_name) VALUES ('Ivanov');
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid;
-ALTER TABLE salesmans SPLIT PARTITION salesmans2_5 INTO
- (PARTITION salesmans2_3 FOR VALUES FROM (2) TO (3),
- PARTITION salesmans3_4 FOR VALUES FROM (3) TO (4),
- PARTITION salesmans4_5 FOR VALUES FROM (4) TO (5));
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
-INSERT INTO salesmans (salesman_name) VALUES ('May');
-INSERT INTO salesmans (salesman_name) VALUES ('Ford');
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
-SELECT * FROM salesmans1_2;
-SELECT * FROM salesmans2_3;
-SELECT * FROM salesmans3_4;
-SELECT * FROM salesmans4_5;
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans1_2'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid;
-- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans2_3'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans3_4'::regclass::oid;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salesmans4_5'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split partition with deleted columns
--
-CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id);
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
-CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
-- Create new partition with some deleted columns:
-CREATE TABLE salesmans10_40(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, d2 INT, d3 DATE, salesman_name VARCHAR(30));
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
-INSERT INTO salesmans10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
-INSERT INTO salesmans10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
-ALTER TABLE salesmans10_40 DROP COLUMN d1;
-ALTER TABLE salesmans10_40 DROP COLUMN d2;
-ALTER TABLE salesmans10_40 DROP COLUMN d3;
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
-ALTER TABLE salesmans ATTACH PARTITION salesmans10_40 FOR VALUES FROM (10) TO (40);
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
-INSERT INTO salesmans VALUES (1, 'Poirot');
-INSERT INTO salesmans VALUES (10, 'May');
-INSERT INTO salesmans VALUES (30, 'Ford');
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
-ALTER TABLE salesmans SPLIT PARTITION salesmans10_40 INTO
- (PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20),
- PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30),
- PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40));
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
-select * from salesmans01_10;
-select * from salesmans10_20;
-select * from salesmans20_30;
-select * from salesmans30_40;
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
-DROP TABLE salesmans CASCADE;
+DROP TABLE salespeople CASCADE;
--
-- Test: split sub-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_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01');
@@ -611,8 +611,8 @@ DROP TABLE sales_range;
-- Test: specific errors for BY LIST partitioning
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -648,8 +648,8 @@ DROP TABLE sales_list;
-- * new partitions do not have a value that split partition has.
--
CREATE TABLE sales_list
-(salesman_id INT,
- salesman_name VARCHAR(30),
+(salesperson_id INT,
+ salesperson_name VARCHAR(30),
sales_state VARCHAR(20),
sales_amount INT,
sales_date DATE)
@@ -676,34 +676,34 @@ DROP TABLE sales_list;
-- Test: BY LIST partitioning, SPLIT PARTITION with data
--
CREATE TABLE sales_list
-(salesman_id SERIAL,
- salesman_name VARCHAR(30),
+(salesperson_id SERIAL,
+ salesperson_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_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 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', 'Warsaw', 750, '2022-03-04');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 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', 'Oslo', 1200, '2022-03-11');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
-INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
@@ -722,7 +722,7 @@ SET enable_seqscan = OFF;
SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
-SELECT * FROM sales_list WHERE salesman_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
SET enable_indexscan = ON;
SET enable_seqscan = ON;
@@ -734,7 +734,7 @@ DROP TABLE sales_list;
-- * split DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
@@ -772,7 +772,7 @@ DROP TABLE sales_range;
-- * split non-DEFAULT partition to partitions with spaces between bounds;
-- * random order of partitions in SPLIT PARTITION command.
--
-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_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -809,7 +809,7 @@ DROP TABLE sales_range;
-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
-- with spaces between bounds.
--
-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_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
--
2.39.3 (Apple Git-145)
v9-0007-Inherit-parent-s-AM-for-partition-MERGE-SPLIT-ope.patchapplication/octet-stream; name=v9-0007-Inherit-parent-s-AM-for-partition-MERGE-SPLIT-ope.patchDownload
From 72a122beae65917906a32767d715a9325aa12d97 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 13:21:14 +0300
Subject: [PATCH v9 7/7] Inherit parent's AM for partition MERGE/SPLIT
operations
This commit makes new partitions created by ALTER TABLE ... SPLIT PARTITION
and ALTER TABLE ... MERGE PARTITIONS commands inherit the paret table access
method.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/84ada05b-be5c-473e-6d1c-ebe5dd21b190%40gmail.com
Reviewed-by: Pavel Borisov
---
doc/src/sgml/ref/alter_table.sgml | 2 ++
src/backend/commands/tablecmds.c | 6 +++++
src/test/regress/expected/partition_merge.out | 18 +++++++++++++++
src/test/regress/expected/partition_split.out | 23 +++++++++++++++++--
src/test/regress/sql/partition_merge.sql | 13 +++++++++++
src/test/regress/sql/partition_split.sql | 14 +++++++++++
6 files changed, 74 insertions(+), 2 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 0f546357863..35c34a3fc90 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1158,6 +1158,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name1</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
The indexes and identity are created later after moving the data
while attaching new partitions.
+ New partitions will have the same table access method as the parent.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
are also created temporary.
@@ -1227,6 +1228,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
The indexes and identity are created later after moving the data
while attaching the new partition.
+ The new partition will have the same table access method as the parent.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
is also created temporary.
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1b89e18eb7e..fd0812cd649 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21187,6 +21187,11 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
* INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
@@ -21217,6 +21222,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
createStmt->oncommit = ONCOMMIT_NOOP;
createStmt->tablespacename = NULL;
createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
tlc = makeNode(TableLikeClause);
tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index a92a270c591..92999703217 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -862,6 +862,24 @@ SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ROLLBACK;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass);
+ relname | amname
+---------+-----------------------
+ tp_0_2 | partitions_merge_heap
+ t | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 55ae37ad370..326fa1bd400 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -85,8 +85,8 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
-LINE 4: PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO...
- ^
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -1494,6 +1494,25 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
(2 rows)
DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass);
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 085c422d540..23795cf9d94 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -535,6 +535,19 @@ SET search_path = partitions_merge_schema, pg_temp, public;
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ROLLBACK;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass);
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
RESET search_path;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 3a7f2f9c294..73e8c2fbeb9 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -880,6 +880,20 @@ SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid)
DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass);
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
--
2.39.3 (Apple Git-145)
v9-0006-Add-tab-completion-for-partition-MERGE-SPLIT-oper.patchapplication/octet-stream; name=v9-0006-Add-tab-completion-for-partition-MERGE-SPLIT-oper.patchDownload
From 0a49f45bf3dbb2a5940b62ec405118c92f4e42aa Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Mon, 22 Apr 2024 13:20:11 +0300
Subject: [PATCH v9 6/7] Add tab completion for partition MERGE/SPLIT
operations
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
This commit implements psql tab completion for ALTER TABLE ... SPLIT PARTITION
and ALTER TABLE ... MERGE PARTITIONS commands.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/5dee3937-8e9f-cca4-11fb-737709a92b37%40gmail.com
Author: Dagfinn Ilmari Mannsåker, Pavel Borisov
---
src/bin/psql/tab-complete.c | 18 ++++++++++++++++--
1 file changed, 16 insertions(+), 2 deletions(-)
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 6fee3160f02..97cd5d9f628 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2609,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2620,6 +2621,19 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
--
2.39.3 (Apple Git-145)
Hi Justin,
Thank you for your review. Please check v9 of the patchset [1].
On Wed, Apr 24, 2024 at 11:26 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
This patch also/already fixes the schema issue I reported. Thanks.
If you wanted to include a test case for that:
begin;
CREATE SCHEMA s;
CREATE SCHEMA t;
CREATE TABLE p(i int) PARTITION BY RANGE(i);
CREATE TABLE s.c1 PARTITION OF p FOR VALUES FROM (1)TO(2);
CREATE TABLE s.c2 PARTITION OF p FOR VALUES FROM (2)TO(3);
ALTER TABLE p MERGE PARTITIONS (s.c1, s.c2) INTO s.c1; -- misbehaves if merging into the same name as an existing partition
\d+ p
...
Partitions: c1 FOR VALUES FROM (1) TO (3)
There is already a test which checks merging into the same name as an
existing partition. And there are tests with schema-qualified names.
I'm not yet convinced we need a test with both these properties
together.
0002
The persistence of the new partition is copied as suggested in [1].
But the checks are in-place, because search_path could influence new
table persistence. Per review [2], commit message typos are fixed,
documentation is revised, revised tests to cover schema-qualification,
usage of search_path.Subject: [PATCH v8 2/7] Make new partitions with parent's persistence during MERGE/SPLIT operations
This patch adds documentation saying: + Any indexes, constraints and user-defined row-level triggers that exist + in the parent table are cloned on new partitions [...]Which is good to say, and addresses part of my message [0]
[0] ZiJW1g2nbQs9ekwK@pryzbyj2023But it doesn't have anything to do with "creating new partitions with
parent's persistence". Maybe there was a merge conflict and the docs
ended up in the wrong patch ?
Makes sense. Extracted this into a separate patch in v10.
Also, defaults, storage options, compression are also copied. As will
be anything else from LIKE. And since anything added in the future will
also be copied, maybe it's better to just say that the tables will be
created the same way as "LIKE .. INCLUDING ALL EXCLUDING ..", or
similar. Otherwise, the next person who adds a new option for LIKE
would have to remember to update this paragraph...
Reworded that way. Thank you.
Also, extended stats objects are currently cloned to new child tables.
But I suggested in [0] that they probably shouldn't be.
I will explore this. Do we copy extended stats when we do CREATE
TABLE ... PARTITION OF? I think we need to do the same here.
007 – doc review by Justin [3]
I suggest to drop this patch for now. I'll send some more minor fixes to
docs and code comments once the other patches are settled.
Your edits are welcome. Dropped this for now. And waiting for the
next revision from you.
Links.
1. /messages/by-id/CAPpHfduYuYECrqpHMgcOsNr+4j3uJK+JPUJ_zDBn-tqjjh3p1Q@mail.gmail.com
------
Regards,
Alexander Korotkov
Supabase
Hello,
28.04.2024 03:59, Alexander Korotkov wrote:
The revised patchset is attached. I'm going to push it if there are
no objections.
I have one additional question regarding security, if you don't mind:
What permissions should a user have to perform split/merge?
When we deal with mixed ownership, say, bob is an owner of a
partitioned table, but not an owner of a partition, should we
allow him to perform merge with that partition?
Consider the following script:
CREATE ROLE alice;
GRANT CREATE ON SCHEMA public TO alice;
SET SESSION AUTHORIZATION alice;
CREATE TABLE t (i int PRIMARY KEY, t text, u text) PARTITION BY RANGE (i);
CREATE TABLE tp_00 PARTITION OF t FOR VALUES FROM (0) TO (10);
CREATE TABLE tp_10 PARTITION OF t FOR VALUES FROM (10) TO (20);
CREATE POLICY p1 ON tp_00 USING (u = current_user);
ALTER TABLE tp_00 ENABLE ROW LEVEL SECURITY;
INSERT INTO t(i, t, u) VALUES (0, 'info for bob', 'bob');
INSERT INTO t(i, t, u) VALUES (1, 'info for alice', 'alice');
RESET SESSION AUTHORIZATION;
CREATE ROLE bob;
GRANT CREATE ON SCHEMA public TO bob;
ALTER TABLE t OWNER TO bob;
GRANT SELECT ON TABLE tp_00 TO bob;
SET SESSION AUTHORIZATION bob;
SELECT * FROM tp_00;
--- here bob can see his info only
\d
Schema | Name | Type | Owner
--------+-------+-------------------+-------
public | t | partitioned table | bob
public | tp_00 | table | alice
public | tp_10 | table | alice
-- but then bob can do:
ALTER TABLE t MERGE PARTITIONS (tp_00, tp_10) INTO tp_00;
-- (yes, he also can detach the partition tp_00, but then he couldn't
-- re-attach nor read it)
\d
Schema | Name | Type | Owner
--------+-------+-------------------+-------
public | t | partitioned table | bob
public | tp_00 | table | bob
Thus bob effectively have captured the partition with the data.
What do you think, does this create a new security risk?
Best regards,
Alexander
On Sun, Apr 28, 2024 at 2:00 PM Alexander Lakhin <exclusion@gmail.com> wrote:
28.04.2024 03:59, Alexander Korotkov wrote:
The revised patchset is attached. I'm going to push it if there are
no objections.I have one additional question regarding security, if you don't mind:
What permissions should a user have to perform split/merge?When we deal with mixed ownership, say, bob is an owner of a
partitioned table, but not an owner of a partition, should we
allow him to perform merge with that partition?
Consider the following script:
CREATE ROLE alice;
GRANT CREATE ON SCHEMA public TO alice;SET SESSION AUTHORIZATION alice;
CREATE TABLE t (i int PRIMARY KEY, t text, u text) PARTITION BY RANGE (i);
CREATE TABLE tp_00 PARTITION OF t FOR VALUES FROM (0) TO (10);
CREATE TABLE tp_10 PARTITION OF t FOR VALUES FROM (10) TO (20);CREATE POLICY p1 ON tp_00 USING (u = current_user);
ALTER TABLE tp_00 ENABLE ROW LEVEL SECURITY;INSERT INTO t(i, t, u) VALUES (0, 'info for bob', 'bob');
INSERT INTO t(i, t, u) VALUES (1, 'info for alice', 'alice');
RESET SESSION AUTHORIZATION;CREATE ROLE bob;
GRANT CREATE ON SCHEMA public TO bob;
ALTER TABLE t OWNER TO bob;
GRANT SELECT ON TABLE tp_00 TO bob;SET SESSION AUTHORIZATION bob; SELECT * FROM tp_00; --- here bob can see his info only \d Schema | Name | Type | Owner --------+-------+-------------------+------- public | t | partitioned table | bob public | tp_00 | table | alice public | tp_10 | table | alice-- but then bob can do:
ALTER TABLE t MERGE PARTITIONS (tp_00, tp_10) INTO tp_00;
-- (yes, he also can detach the partition tp_00, but then he couldn't
-- re-attach nor read it)\d
Schema | Name | Type | Owner
--------+-------+-------------------+-------
public | t | partitioned table | bob
public | tp_00 | table | bobThus bob effectively have captured the partition with the data.
What do you think, does this create a new security risk?
Alexander, thank you for discovering this. I believe that the one who
merges partitions should have permissions for all the partitions
merged. I'll recheck this and provide the patch.
------
Regards,
Alexander Korotkov
On Sun, Apr 28, 2024 at 04:04:54AM +0300, Alexander Korotkov wrote:
Hi Justin,
Thank you for your review. Please check v9 of the patchset [1].
On Wed, Apr 24, 2024 at 11:26 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
This patch also/already fixes the schema issue I reported. Thanks.
If you wanted to include a test case for that:
begin;
CREATE SCHEMA s;
CREATE SCHEMA t;
CREATE TABLE p(i int) PARTITION BY RANGE(i);
CREATE TABLE s.c1 PARTITION OF p FOR VALUES FROM (1)TO(2);
CREATE TABLE s.c2 PARTITION OF p FOR VALUES FROM (2)TO(3);
ALTER TABLE p MERGE PARTITIONS (s.c1, s.c2) INTO s.c1; -- misbehaves if merging into the same name as an existing partition
\d+ p
...
Partitions: c1 FOR VALUES FROM (1) TO (3)There is already a test which checks merging into the same name as an
existing partition. And there are tests with schema-qualified names.
I'm not yet convinced we need a test with both these properties
together.
I mentioned that the combination of schemas and merge-into-same-name is
what currently doesn't work right.
Also, extended stats objects are currently cloned to new child tables.
But I suggested in [0] that they probably shouldn't be.I will explore this. Do we copy extended stats when we do CREATE
TABLE ... PARTITION OF? I think we need to do the same here.
Right, they're not copied because an extended stats objs on the parent
does something different than putting stats objects on each child.
I've convinced myself that it's wrong to copy the parent's stats obj.
If someone wants stats objects on each child, they'll have to handle
them specially after MERGE/SPLIT, just as they would for per-child
defaults/constraints/etc.
On Sun, Apr 28, 2024 at 04:04:54AM +0300, Alexander Korotkov wrote:
On Wed, Apr 24, 2024 at 11:26 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
This patch adds documentation saying: + Any indexes, constraints and user-defined row-level triggers that exist + in the parent table are cloned on new partitions [...]Which is good to say, and addresses part of my message [0]
[0] ZiJW1g2nbQs9ekwK@pryzbyj2023Makes sense. Extracted this into a separate patch in v10.
I adjusted the language some and fixed a typo in the commit message.
s/parition/partition/
--
Justin
Attachments:
0001-Document-the-way-partition-MERGE-SPLIT-operations-cr.patchtext/x-diff; charset=us-asciiDownload
From e00033fc4b8254c70bf8a3d41d513edd9540e2d7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 28 Apr 2024 03:39:30 +0300
Subject: [PATCH] Document the way partition MERGE/SPLIT operations create new
partitions
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZilrByTp-pbz6Mvf%40pryzbyj2023
---
doc/src/sgml/ref/alter_table.sgml | 12 ++++++++++++
1 file changed, 12 insertions(+)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index fe36ff82e52..fc2dfffe49f 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1153,6 +1153,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
splitting we have a partition with the same name).
Only simple, non-partitioned partition can be split.
</para>
+ <para>
+ The new partitions will be created the same as tables created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
@@ -1213,6 +1219,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
can have the same name as one of the merged partitions. Only simple,
non-partitioned partitions can be merged.
</para>
+ <para>
+ The new partition will be created the same as a table created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ </para>
<note>
<para>
This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
--
2.42.0
On Sunday, April 28, 2024, Alexander Lakhin <exclusion@gmail.com> wrote:
When we deal with mixed ownership, say, bob is an owner of a
partitioned table, but not an owner of a partition, should we
allow him to perform merge with that partition?
IIUC Merge causes the source tables to be dropped, their data having been
effectively moved into the new partition. bob must not be allowed to drop
Alice’s tables. Only an owner may do that. So if we do allow bob to build
a new partition using his select access, the tables he selected from would
have to remain behind if he is not an owner of them.
David J.
On Sunday, April 28, 2024, Alexander Lakhin <exclusion@gmail.com> wrote:
When we deal with mixed ownership, say, bob is an owner of a
partitioned table, but not an owner of a partition, should we
allow him to perform merge with that partition?
Attaching via alter table requires the user to own both the partitioned
table and the table being acted upon. Merge needs to behave similarly.
The fact that we let the superuser break the requirement of common
ownership is unfortunate but I guess understandable. But given the
existing behavior of attach merge should likewise fail if it find the user
doesn’t own the partitions being merged. The fact that the user can select
from those tables can be acted upon manually if desired; these
administrative commands should all ensure common ownership and fail if that
precondition is not met.
David J.
On Sun, Apr 28, 2024 at 08:18:42AM -0500, Justin Pryzby wrote:
I will explore this. Do we copy extended stats when we do CREATE
TABLE ... PARTITION OF? I think we need to do the same here.Right, they're not copied because an extended stats objs on the parent
does something different than putting stats objects on each child.
I've convinced myself that it's wrong to copy the parent's stats obj.
If someone wants stats objects on each child, they'll have to handle
them specially after MERGE/SPLIT, just as they would for per-child
defaults/constraints/etc.
I dug up this thread, in which the idea of copying extended stats from
parent to child was considered some 6 years ago, but never implemented;
for consistency, MERGE/SPLIT shouldn't copy extended stats, either.
/messages/by-id/20180305195750.aecbpihhcvuskzba@alvherre.pgsql
--
Justin
Hi Dmitry,
19.04.2024 02:26, Dmitry Koval wrote:
18.04.2024 19:00, Alexander Lakhin wrote:
leaves a strange constraint:
\d+ t*
Table "public.tp_0"
...
Not-null constraints:
"merge-16385-26BCB0-tmp_i_not_null" NOT NULL "i"Thanks!
Attached fix (with test) for this case.
The patch should be applied after patches
v6-0001- ... .patch ... v6-0004- ... .patch
I still wonder, why that constraint (now with a less questionable name) is
created during MERGE?
That is, before MERGE, two partitions have only PRIMARY KEY indexes,
with no not-null constraint, and you can manually remove the constraint
after MERGE, so maybe it's not necessary...
Best regards,
Alexander
Hi!
1.
29.04.2024 21:00, Alexander Lakhin wrote:
I still wonder, why that constraint (now with a less questionable name) is
created during MERGE?
The SPLIT/MERGE PARTITION(S) commands for creating partitions reuse the
existing code of CREATE TABLE .. LIKE ... command. A new partition was
created with the name "merge-16385-26BCB0-tmp" (since there was an old
partition with the same name). The constraint
"merge-16385-26BCB0-tmp_i_not_null" was created too together with the
partition. Subsequently, the table was renamed, but the constraint was not.
Now a new partition is immediately created with the correct name (the
old partition is renamed).
2.
Just in case, I am attaching a small fix v9_fix.diff for situation [1]/messages/by-id/0520c72e-8d97-245e-53f9-173beca2ab2e@gmail.com.
[1]: /messages/by-id/0520c72e-8d97-245e-53f9-173beca2ab2e@gmail.com
/messages/by-id/0520c72e-8d97-245e-53f9-173beca2ab2e@gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v9_fix.difftext/plain; charset=UTF-8; name=v9_fix.diffDownload
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index fef084f5d5..e918a623c5 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3446,6 +3446,11 @@ checkPartition(Relation rel, Oid partRelOid)
RelationGetRelationName(partRel),
RelationGetRelationName(rel))));
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
relation_close(partRel, AccessShareLock);
}
30.04.2024 03:10, Dmitry Koval wrote:
Hi!
1.
29.04.2024 21:00, Alexander Lakhin wrote:I still wonder, why that constraint (now with a less questionable name) is
created during MERGE?The SPLIT/MERGE PARTITION(S) commands for creating partitions reuse the existing code of CREATE TABLE .. LIKE ...
command. A new partition was created with the name "merge-16385-26BCB0-tmp" (since there was an old partition with the
same name). The constraint "merge-16385-26BCB0-tmp_i_not_null" was created too together with the partition.
Subsequently, the table was renamed, but the constraint was not.
Now a new partition is immediately created with the correct name (the old partition is renamed).
Maybe I'm doing something wrong, but the following script:
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);
CREATE TABLE t2 (LIKE t INCLUDING ALL);
CREATE TABLE tp2 (LIKE tp_0 INCLUDING ALL);
creates tables t2, tp2 without not-null constraints.
But after
ALTER TABLE t MERGE PARTITIONS (tp_0, tp_1) INTO tp_0;
I see:
\d+ tp_0
...
Indexes:
"tp_0_pkey" PRIMARY KEY, btree (i)
Not-null constraints:
"tp_0_i_not_null" NOT NULL "i"
Best regards,
Alexander
On Thu, Apr 11, 2024 at 08:00:00PM +0300, Alexander Lakhin wrote:
11.04.2024 16:27, Dmitry Koval wrote:
Added correction (and test), see v3-0001-Fix-for-SPLIT-MERGE-partitions-of-temporary-table.patch.
Thank you for the correction, but may be an attempt to merge into implicit
pg_temp should fail just like CREATE TABLE ... PARTITION OF ... does?Please look also at another anomaly with schemas:
CREATE SCHEMA s1;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t
� FOR VALUES FROM (0) TO (2);
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
� (PARTITION s1.tp0 FOR VALUES FROM (0) TO (1), PARTITION s1.tp1 FOR VALUES FROM (1) TO (2));
results in:
\d+ s1.*
Did not find any relation named "s1.*"
\d+ tp*
����������������������������������������� Table "public.tp0"
Hi,
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?
Thanks,
--
Justin
Hi!
30.04.2024 6:00, Alexander Lakhin пишет:
Maybe I'm doing something wrong, but the following script:
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);CREATE TABLE t2 (LIKE t INCLUDING ALL);
CREATE TABLE tp2 (LIKE tp_0 INCLUDING ALL);
creates tables t2, tp2 without not-null constraints.
To create partitions is used the "CREATE TABLE ... LIKE ..." command
with the "EXCLUDING INDEXES" modifier (to speed up the insertion of values).
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE(i);
CREATE TABLE t2 (LIKE t INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY);
\d+ t2;
...
Not-null constraints:
"t2_i_not_null" NOT NULL "i"
Access method: heap
[1]: https://github.com/postgres/postgres/blob/d12b4ba1bd3eedd862064cf1dad5ff107c5cba90/src/backend/commands/tablecmds.c#L21215 -- With best regards, Dmitry Koval
https://github.com/postgres/postgres/blob/d12b4ba1bd3eedd862064cf1dad5ff107c5cba90/src/backend/commands/tablecmds.c#L21215
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi!
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?
I think this was fixed in commit [1]https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91.
[1]: https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Wed, May 01, 2024 at 10:51:24PM +0300, Dmitry Koval wrote:
Hi!
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?I think this was fixed in commit [1].
[1] https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
I tried to reproduce it at fcf80c5d5f~, but couldn't.
I don't see how that patch would fix it anyway.
I'm hoping Alexander can confirm what happened.
The other remaining issues I'm aware of are for EXCLUDING STATISTICS and
refusing to ALTER if the owners don't match.
Note that the error that led to "EXCLUDING IDENTITY" is being discused
over here:
/messages/by-id/3b8a9dc1-bbc7-0ef5-6863-c432afac7d59@gmail.com
It's possible that once that's addressed, the exclusion should be
removed here, too.
--
Justin
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Wed, May 01, 2024 at 10:51:24PM +0300, Dmitry Koval wrote:
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?I think this was fixed in commit [1].
[1] https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
I tried to reproduce it at fcf80c5d5f~, but couldn't.
I don't see how that patch would fix it anyway.
I'm hoping Alexander can confirm what happened.
This problem is only relevant for an old version of fix [1], which
overrides schemas for new partitions. That version was never
committed.
The other remaining issues I'm aware of are for EXCLUDING STATISTICS and
refusing to ALTER if the owners don't match.
These two are in my list. I'm planning to work on them in the next few days.
Note that the error that led to "EXCLUDING IDENTITY" is being discused
over here:
/messages/by-id/3b8a9dc1-bbc7-0ef5-6863-c432afac7d59@gmail.comIt's possible that once that's addressed, the exclusion should be
removed here, too.
+1
Links.
1. /messages/by-id/edfbd846-dcc1-42d1-ac26-715691b687d3@postgrespro.ru
------
Regards,
Alexander Korotkov
Supabase
On Fri, May 3, 2024 at 4:32 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Wed, May 01, 2024 at 10:51:24PM +0300, Dmitry Koval wrote:
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?I think this was fixed in commit [1].
[1] https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
I tried to reproduce it at fcf80c5d5f~, but couldn't.
I don't see how that patch would fix it anyway.
I'm hoping Alexander can confirm what happened.This problem is only relevant for an old version of fix [1], which
overrides schemas for new partitions. That version was never
committed.
Here are the patches.
0001 Adds permission checks on the partitions before doing MERGE/SPLIT
0002 Skips copying extended statistics while creating new partitions
in MERGE/SPLIT
0001 looks quite simple and trivial for me. I'm going to push it if
no objections.
For 0002 I'd like to hear some feedback on wordings used in docs and comments.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v1-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchapplication/octet-stream; name=v1-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchDownload
From 1a0dcde924ce020d8e3ff7242a8874bc3da70bfa Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Wed, 8 May 2024 20:32:20 +0300
Subject: [PATCH v1 2/2] Don't copy extended statistics during MERGE/SPLIT
partition operations
Currenlty MERGE/SPLIT partition operations create new partiions copying the
extended statistics from the parent table. However, parent's table extended
statistics already covers all its children. Also, "CREATE TABLE ... PARTITION
OF" command doesn't copy extended statistics. This commit makes
createPartitionTable() skip copying extended statistics from the parent.
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZiJW1g2nbQs9ekwK%40pryzbyj2023
---
doc/src/sgml/ref/alter_table.sgml | 8 ++++--
src/backend/commands/tablecmds.c | 8 +++---
src/test/regress/expected/partition_merge.out | 17 ++++++++++++
src/test/regress/expected/partition_split.out | 27 +++++++++++++++++++
src/test/regress/sql/partition_merge.sql | 10 +++++++
src/test/regress/sql/partition_split.sql | 12 +++++++++
6 files changed, 77 insertions(+), 5 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 0bf11f6cb6d..a11a407b7a6 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1155,9 +1155,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partitions will be created the same as tables created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partitions.
+ The extended statistics aren't copied from the parent table, since
+ the parent's statistics cover all children and it's typically enough.
New partitions will have the same table access method as the parent.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
@@ -1225,9 +1227,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partition will be created the same as a table created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partition.
+ The extended statistics aren't copied from the parent table, since
+ the parent's statistics cover all children and it's typically enough.
The new partition will have the same table access method as the parent.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5bf5e69c5b8..dddf694b787 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21245,7 +21245,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* (newPartName) like table (modelRel)
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
- * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
*
* Also, this function sets the new partition access method same as parent
* table access methods (similarly to CREATE TABLE ... PARTITION OF). It
@@ -21289,9 +21289,11 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
/*
* Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * moving. We also don't copy the extended statistics since the parent's
+ * statistics cover all children and it's typically enough.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY);
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 076264c88eb..36a60d7472c 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -910,6 +910,23 @@ RESET SESSION AUTHORIZATION;
DROP TABLE t;
DROP ROLE regress_partition_merge_alice;
DROP ROLE regress_partition_merge_bob;
+-- Check extended statistics aren't copied from the parent table to the new
+-- partition.
+CREATE TABLE t (i int, j int) PARTITION BY RANGE (i);
+CREATE STATISTICS t_i_j (mcv) ON i, j FROM t;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+\d+ tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | | | plain | |
+ j | integer | | | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+
+DROP TABLE t;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 74e19d250e9..461318db867 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1543,6 +1543,33 @@ RESET SESSION AUTHORIZATION;
DROP TABLE t;
DROP ROLE regress_partition_merge_alice;
DROP ROLE regress_partition_merge_bob;
+-- Check extended statistics aren't copied from the parent table to new
+-- partitions.
+CREATE TABLE t (i int, j int) PARTITION BY RANGE (i);
+CREATE STATISTICS t_i_j (mcv) ON i, j FROM t;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+\d+ tp_0_1
+ Table "partition_split_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | | | plain | |
+ j | integer | | | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 1))
+
+\d+ tp_1_2
+ Table "partition_split_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | | | plain | |
+ j | integer | | | | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 1) AND (i < 2))
+
+DROP TABLE t;
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 9bfeb0d7ef3..203811b6e39 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -582,6 +582,16 @@ DROP TABLE t;
DROP ROLE regress_partition_merge_alice;
DROP ROLE regress_partition_merge_bob;
+-- Check extended statistics aren't copied from the parent table to the new
+-- partition.
+CREATE TABLE t (i int, j int) PARTITION BY RANGE (i);
+CREATE STATISTICS t_i_j (mcv) ON i, j FROM t;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+\d+ tp_0_2
+DROP TABLE t;
+
RESET search_path;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index bb52514b7ed..dc7424256e8 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -927,6 +927,18 @@ DROP TABLE t;
DROP ROLE regress_partition_merge_alice;
DROP ROLE regress_partition_merge_bob;
+-- Check extended statistics aren't copied from the parent table to new
+-- partitions.
+CREATE TABLE t (i int, j int) PARTITION BY RANGE (i);
+CREATE STATISTICS t_i_j (mcv) ON i, j FROM t;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+\d+ tp_0_1
+\d+ tp_1_2
+DROP TABLE t;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
v1-0001-Add-permission-check-for-MERGE-SPLIT-partition-op.patchapplication/octet-stream; name=v1-0001-Add-permission-check-for-MERGE-SPLIT-partition-op.patchDownload
From 02e3ca736fdc7425ccec294a9bc5fae8b82bc673 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Wed, 8 May 2024 17:30:09 +0300
Subject: [PATCH v1 1/2] Add permission check for MERGE/SPLIT partition
operations
Currently, we check only owner permission for the parent table before
MERGE/SPLIT partition operations. This leads to a security hole when users
can get access to the data of partitions without permission. This commit
fixes this problem by requiring owner permission on all the partitions
involved.
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/0520c72e-8d97-245e-53f9-173beca2ab2e%40gmail.com
Author: Dmitry Koval, Alexander Korotkov
---
src/backend/parser/parse_utilcmd.c | 5 +++
src/test/regress/expected/partition_merge.out | 29 ++++++++++++++++
src/test/regress/expected/partition_split.out | 29 ++++++++++++++++
src/test/regress/sql/partition_merge.sql | 33 +++++++++++++++++++
src/test/regress/sql/partition_split.sql | 33 +++++++++++++++++++
5 files changed, 129 insertions(+)
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6520bf9baa5..0598e897d90 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3456,6 +3456,11 @@ checkPartition(Relation rel, Oid partRelOid)
RelationGetRelationName(partRel),
RelationGetRelationName(rel))));
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
relation_close(partRel, AccessShareLock);
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 52e5c3ce0da..076264c88eb 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -881,6 +881,35 @@ ORDER BY c.relname;
DROP TABLE t;
DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 641e1acc3d7..74e19d250e9 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1514,6 +1514,35 @@ ORDER BY c.relname;
DROP TABLE t;
DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
--
DROP SCHEMA partition_split_schema;
DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 84a3462205a..9bfeb0d7ef3 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -549,6 +549,39 @@ ORDER BY c.relname;
DROP TABLE t;
DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
RESET search_path;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index d2c687c41ba..bb52514b7ed 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -894,6 +894,39 @@ ORDER BY c.relname;
DROP TABLE t;
DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
--
DROP SCHEMA partition_split_schema;
--
2.39.3 (Apple Git-145)
On Wed, May 1, 2024 at 12:14 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
30.04.2024 6:00, Alexander Lakhin пишет:
Maybe I'm doing something wrong, but the following script:
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
CREATE TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);CREATE TABLE t2 (LIKE t INCLUDING ALL);
CREATE TABLE tp2 (LIKE tp_0 INCLUDING ALL);
creates tables t2, tp2 without not-null constraints.To create partitions is used the "CREATE TABLE ... LIKE ..." command
with the "EXCLUDING INDEXES" modifier (to speed up the insertion of
values).
CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE(i);
CREATE TABLE t2 (LIKE t INCLUDING ALL EXCLUDING INDEXES EXCLUDING
IDENTITY);
\d+ t2;
...
Not-null constraints:
"t2_i_not_null" NOT NULL "i"
Access method: heap
I've explored this a little bit more.
If the parent table has explicit not null constraint than results of
MERGE/SPLIT look the same as result of CREATE TABLE ... PARTITION OF. In
every case there is explicit not null constraint in all the cases.
# CREATE TABLE t (i int not null, PRIMARY KEY(i)) PARTITION BY RANGE(i);
# \d+ t
Partitioned table "public.t"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition key: RANGE (i)
Indexes:
"t_pkey" PRIMARY KEY, btree (i)
Not-null constraints:
"t_i_not_null" NOT NULL "i"
Number of partitions: 0
# CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
# \d+ tp_0_2
Table "public.tp_0_2"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
Indexes:
"tp_0_2_pkey" PRIMARY KEY, btree (i)
Not-null constraints:
"t_i_not_null" NOT NULL "i" (inherited)
Access method: heap
# ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
# (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
# PARTITION tp_1_2 FOR VALUES FROM (1) TO (2))
# \d+ tp_0_1
Table "public.tp_0_1"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (1)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 1))
Indexes:
"tp_0_1_pkey" PRIMARY KEY, btree (i)
Not-null constraints:
"t_i_not_null" NOT NULL "i" (inherited)
Access method: heap
However, if not null constraint is implicit and derived from primary key,
the situation is different. The partition created by CREATE TABLE ...
PARTITION OF doesn't have explicit not null constraint just like the
parent. But the partition created by MERGE/SPLIT has explicit not null
contraint.
# CREATE TABLE t (i int not null, PRIMARY KEY(i)) PARTITION BY RANGE(i);
# \d+ t
Partitioned table "public.t"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition key: RANGE (i)
Indexes:
"t_pkey" PRIMARY KEY, btree (i)
Number of partitions: 0
# CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
# \d+ tp_0_2
Table "public.tp_0_2"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
Indexes:
"tp_0_2_pkey" PRIMARY KEY, btree (i)
Access method: heap
# ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
# (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
# PARTITION tp_1_2 FOR VALUES FROM (1) TO (2))
# \d+ tp_0_1
Table "public.tp_0_1"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Partition of: t FOR VALUES FROM (0) TO (1)
Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 1))
Indexes:
"tp_0_1_pkey" PRIMARY KEY, btree (i)
Not-null constraints:
"tp_0_1_i_not_null" NOT NULL "i"
Access method: heap
I think this is related to the fact that we create indexes later. The same
applies to CREATE TABLE ... LIKE. If we create indexes immediately, not
explicit not null contraints are created. Not if we do without indexes, we
have an explicit not null constraint.
# CREATE TABLE t2 (LIKE t INCLUDING ALL);
# \d+ t2
Table "public.t2"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Not-null constraints:
"t2_i_not_null" NOT NULL "i"
Access method: heap
# CREATE TABLE t3 (LIKE t INCLUDING ALL EXCLUDING IDENTITY);
# \d+ t3
Table "public.t3"
Column | Type | Collation | Nullable | Default | Storage | Compression
| Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | not null | | plain |
| |
Indexes:
"t3_pkey" PRIMARY KEY, btree (i)
Access method: heap
I think this is feasible to avoid. However, it's minor and we exactly
documented how we create new partitions. So, I think it works "as
documented" and we don't have to fix this for v17.
------
Regards,
Alexander Korotkov
Supabase
On Wed, May 08, 2024 at 09:00:10PM +0300, Alexander Korotkov wrote:
On Fri, May 3, 2024 at 4:32 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Wed, May 01, 2024 at 10:51:24PM +0300, Dmitry Koval wrote:
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?I think this was fixed in commit [1].
[1] https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
I tried to reproduce it at fcf80c5d5f~, but couldn't.
I don't see how that patch would fix it anyway.
I'm hoping Alexander can confirm what happened.This problem is only relevant for an old version of fix [1], which
overrides schemas for new partitions. That version was never
committed.Here are the patches.
0002 Skips copying extended statistics while creating new partitions in MERGE/SPLITFor 0002 I'd like to hear some feedback on wordings used in docs and comments.
commit message:
Currenlty => Currently
partiions => partitios
copying => by copying
However, parent's table extended statistics already covers all its
children.
=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and in the
catalog.
The right explanation is that extended stats on partitioned tables are
not similar to indexes. Indexes on parent table are nothing other than
a mechanism to create indexes on the child tables. That's not true for
stats.
See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023
I think EXCLUDE IDENTITY can/should now also be removed - see 509199587.
I'm not able to reproduce that problem anyway, even before that...
--
Justin
On Thu, May 9, 2024 at 12:37 AM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Wed, May 08, 2024 at 09:00:10PM +0300, Alexander Korotkov wrote:
On Fri, May 3, 2024 at 4:32 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Wed, May 01, 2024 at 10:51:24PM +0300, Dmitry Koval wrote:
30.04.2024 23:15, Justin Pryzby пишет:
Is this issue already fixed ?
I wasn't able to reproduce it. Maybe it only happened with earlier
patch versions applied ?I think this was fixed in commit [1].
[1] https://github.com/postgres/postgres/commit/fcf80c5d5f0f3787e70fca8fd029d2e08a923f91
I tried to reproduce it at fcf80c5d5f~, but couldn't.
I don't see how that patch would fix it anyway.
I'm hoping Alexander can confirm what happened.This problem is only relevant for an old version of fix [1], which
overrides schemas for new partitions. That version was never
committed.Here are the patches.
0002 Skips copying extended statistics while creating new partitions in MERGE/SPLITFor 0002 I'd like to hear some feedback on wordings used in docs and comments.
commit message:
Currenlty => Currently
partiions => partitios
copying => by copying
Thank you!
However, parent's table extended statistics already covers all its
children.=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and in the
catalog.The right explanation is that extended stats on partitioned tables are
not similar to indexes. Indexes on parent table are nothing other than
a mechanism to create indexes on the child tables. That's not true for
stats.See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023
Yes, I understand that parents pg_statistic entry with stainherit ==
true includes statistics for the children. I tried to express this by
word "covers". But you're right, this is the wrong explanation.
Can I, please, ask you to revise the patch?
I think EXCLUDE IDENTITY can/should now also be removed - see 509199587.
I'm not able to reproduce that problem anyway, even before that...
I will check this.
------
Regards,
Alexander Korotkov
Supabase
Hello Dmitry and Alexander,
Please look at one more anomaly with temporary tables:
CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (1) ;
CREATE TEMP TABLE tp_1 PARTITION OF t FOR VALUES FROM (1) TO (2);
ALTER TABLE t MERGE PARTITIONS (tp_0, tp_1) INTO tp_0;
-- succeeds, but:
ALTER TABLE t SPLIT PARTITION tp_0 INTO
(PARTITION tp_0 FOR VALUES FROM (0) TO (1), PARTITION tp_1 FOR VALUES FROM (1) TO (2));
-- fails with:
ERROR: relation "tp_0" already exists
Though the same SPLIT succeeds with non-temporary tables...
Best regards,
Alexander
Hi!
11.05.2024 12:00, Alexander Lakhin wrote:
Please look at one more anomaly with temporary tables:
Thank you, Alexander!
The problem affects the SPLIT PARTITION command.
CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2) ;
-- ERROR: relation "tp_0" already exists
ALTER TABLE t SPLIT PARTITION tp_0 INTO
(PARTITION tp_0 FOR VALUES FROM (0) TO (1), PARTITION tp_1 FOR
VALUES FROM (1) TO (2));
I'll try to fix it soon.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi!
Attached draft version of fix for [1]/messages/by-id/86b4f1e3-0b5d-315c-9225-19860d64d685@gmail.com.
[1]: /messages/by-id/86b4f1e3-0b5d-315c-9225-19860d64d685@gmail.com
/messages/by-id/86b4f1e3-0b5d-315c-9225-19860d64d685@gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v1-0003-Fix-for-the-search-of-temporary-partition-for-the.patchtext/plain; charset=UTF-8; name=v1-0003-Fix-for-the-search-of-temporary-partition-for-the.patchDownload
From ece01564aeb848bab2a61617412a1d175e45b934 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Sun, 12 May 2024 17:17:10 +0300
Subject: [PATCH v1 3/3] Fix for the search of temporary partition for the
SPLIT SECTION operation
---
src/backend/commands/tablecmds.c | 1 +
src/test/regress/expected/partition_split.out | 8 ++++++++
src/test/regress/sql/partition_split.sql | 8 ++++++++
3 files changed, 17 insertions(+)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index fe66d9e58d..a5babcfbc6 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21389,6 +21389,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
* against concurrent drop, and mark stmt->relation as
* RELPERSISTENCE_TEMP if a temporary namespace is selected.
*/
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
namespaceId =
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 461318db86..b1108c92a2 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1569,6 +1569,14 @@ Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 1))
Partition of: t FOR VALUES FROM (1) TO (2)
Partition constraint: ((i IS NOT NULL) AND (i >= 1) AND (i < 2))
+DROP TABLE t;
+-- Check that the search for a temporary partition is correct during
+-- the SPLIT PARTITION operation.
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2) ;
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index dc7424256e..7f231b0d39 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -939,6 +939,14 @@ ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
\d+ tp_1_2
DROP TABLE t;
+-- Check that the search for a temporary partition is correct during
+-- the SPLIT PARTITION operation.
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2) ;
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
--
DROP SCHEMA partition_split_schema;
--
2.34.1
Commit 3ca43dbbb67f which adds the permission checks seems to cause conflicts
in the pg_upgrade tests:
https://buildfarm.postgresql.org/cgi-bin/show_log.pl?nm=piculet&dt=2024-05-13%2008%3A36%3A37
There is an issue with dropping and creating roles which seems to stem from
this commit:
CREATE ROLE regress_partition_merge_alice;
+ERROR: role "regress_partition_merge_alice" already exists
--
Daniel Gustafsson
Hi!
13.05.2024 11:45, Daniel Gustafsson пишет:
Commit 3ca43dbbb67f which adds the permission checks seems to cause conflicts
in the pg_upgrade tests
Thanks!
It will probably be enough to rename the roles:
regress_partition_merge_alice -> regress_partition_split_alice
regress_partition_merge_bob -> regress_partition_split_bob
(changes in attachment)
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v1-0001-Rename-roles-to-avoid-conflicts-in-concurrent-wor.patchtext/plain; charset=UTF-8; name=v1-0001-Rename-roles-to-avoid-conflicts-in-concurrent-wor.patchDownload
From f307add79397bcfe20f7c779e77630fb0df73020 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Mon, 13 May 2024 12:32:43 +0300
Subject: [PATCH v1] Rename roles to avoid conflicts in concurrent work
---
src/test/regress/expected/partition_split.out | 20 +++++++++----------
src/test/regress/sql/partition_split.sql | 20 +++++++++----------
2 files changed, 20 insertions(+), 20 deletions(-)
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index b1108c92a2..999e923ef1 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1516,33 +1516,33 @@ DROP TABLE t;
DROP ACCESS METHOD partition_split_heap;
-- Test permission checks. The user needs to own the parent table and the
-- the partition to split to do the split.
-CREATE ROLE regress_partition_merge_alice;
-CREATE ROLE regress_partition_merge_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
ERROR: must be owner of table t
RESET SESSION AUTHORIZATION;
-ALTER TABLE t OWNER TO regress_partition_merge_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
ERROR: must be owner of table tp_0_2
RESET SESSION AUTHORIZATION;
-ALTER TABLE tp_0_2 OWNER TO regress_partition_merge_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
RESET SESSION AUTHORIZATION;
DROP TABLE t;
-DROP ROLE regress_partition_merge_alice;
-DROP ROLE regress_partition_merge_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
-- Check extended statistics aren't copied from the parent table to new
-- partitions.
CREATE TABLE t (i int, j int) PARTITION BY RANGE (i);
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 7f231b0d39..be4a785b75 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -896,36 +896,36 @@ DROP ACCESS METHOD partition_split_heap;
-- Test permission checks. The user needs to own the parent table and the
-- the partition to split to do the split.
-CREATE ROLE regress_partition_merge_alice;
-CREATE ROLE regress_partition_merge_bob;
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
RESET SESSION AUTHORIZATION;
-ALTER TABLE t OWNER TO regress_partition_merge_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
RESET SESSION AUTHORIZATION;
-ALTER TABLE tp_0_2 OWNER TO regress_partition_merge_bob;
-SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
RESET SESSION AUTHORIZATION;
DROP TABLE t;
-DROP ROLE regress_partition_merge_alice;
-DROP ROLE regress_partition_merge_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
-- Check extended statistics aren't copied from the parent table to new
-- partitions.
--
2.34.1
On Mon, May 13, 2024 at 12:45 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
13.05.2024 11:45, Daniel Gustafsson пишет:
Commit 3ca43dbbb67f which adds the permission checks seems to cause conflicts
in the pg_upgrade testsThanks!
It will probably be enough to rename the roles:
regress_partition_merge_alice -> regress_partition_split_alice
regress_partition_merge_bob -> regress_partition_split_bob
Thanks to Danial for spotting this.
Thanks to Dmitry for the proposed fix.
The actual problem appears to be a bit more complex. Additionally to
the role names, the lack of permissions on schemas lead to creation of
tables in public schema and potential conflict there. Fixed in
2a679ae94e.
------
Regards,
Alexander Korotkov
On Thu, May 09, 2024 at 12:51:32AM +0300, Alexander Korotkov wrote:
However, parent's table extended statistics already covers all its
children.=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and in the
catalog.The right explanation is that extended stats on partitioned tables are
not similar to indexes. Indexes on parent table are nothing other than
a mechanism to create indexes on the child tables. That's not true for
stats.See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023Yes, I understand that parents pg_statistic entry with stainherit ==
true includes statistics for the children. I tried to express this by
word "covers". But you're right, this is the wrong explanation.Can I, please, ask you to revise the patch?
I tried to make this clear but it'd be nice if someone (Tomas/Alvaro?)
would check that this says what's wanted.
--
Justin
Attachments:
0001-Don-t-copy-extended-statistics-during-MERGE-SPLIT-pa.patchtext/x-diff; charset=us-asciiDownload
From 265207e5bdb215600ce5d7b45f627bc41fc2bc26 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Wed, 8 May 2024 20:32:20 +0300
Subject: [PATCH] Don't copy extended statistics during MERGE/SPLIT partition
operations
When MERGE/SPLIT created new partitions, it was cloning the extended
statistics of the parent table.
However, extended stats on partitioned tables are not analgous to
indexes on partitioned tables (which exist only to create physical
indexes on child tables). Rather, extended stats on a parent 1) cause
extended stats to be collected and computed across the whole partition
heirarchy, and 2) do not cause extended stats to be computed for the
individual partitions.
"CREATE TABLE ... PARTITION OF" command doesn't copy extended
statistics. This commit makes createPartitionTable() behave
consistently.
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZiJW1g2nbQs9ekwK%40pryzbyj2023
---
doc/src/sgml/ref/alter_table.sgml | 9 +++++++--
src/backend/commands/tablecmds.c | 8 +++++---
2 files changed, 12 insertions(+), 5 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 891fa4a7a04..313c722ee7f 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1154,9 +1154,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partitions will be created the same as tables created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
New partitions will have the same table access method as the parent.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
@@ -1224,9 +1227,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partition will be created the same as a table created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
The new partition will have the same table access method as the parent.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 79c9c031833..50fc54cb309 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20419,7 +20419,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* (newPartName) like table (modelRel)
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
- * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
*
* Also, this function sets the new partition access method same as parent
* table access methods (similarly to CREATE TABLE ... PARTITION OF). It
@@ -20463,9 +20463,11 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
/*
* Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY);
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
--
2.42.0
On Tue, May 14, 2024 at 5:49 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Thu, May 09, 2024 at 12:51:32AM +0300, Alexander Korotkov wrote:
However, parent's table extended statistics already covers all its
children.=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and in the
catalog.The right explanation is that extended stats on partitioned tables are
not similar to indexes. Indexes on parent table are nothing other than
a mechanism to create indexes on the child tables. That's not true for
stats.See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023Yes, I understand that parents pg_statistic entry with stainherit ==
true includes statistics for the children. I tried to express this by
word "covers". But you're right, this is the wrong explanation.Can I, please, ask you to revise the patch?
I tried to make this clear but it'd be nice if someone (Tomas/Alvaro?)
would check that this says what's wanted.
Thank you!
I've assembled the patches with the pending fixes.
0001 – The patch by Dmitry Koval for fixing detection of name
collision in SPLIT partition operation. Also, I found that name
collision detection doesn't work well for MERGE partitions. I've
added fix for that to this patch as well.
0002 -– Patch for skipping copy of extended statistics. I would
appreciate more feedback about wording, but I'd like to get a correct
behavior into the source tree sooner. If the docs and/or comments
need further improvements, we can fix that later.
I'm going to push both if no objections.
Links.
1. /messages/by-id/147426d9-b793-4571-a5e5-7438affeeb5a@postgrespro.ru
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v2-0001-Fix-the-name-collision-detection-in-MERGE-SPLIT-p.patchapplication/octet-stream; name=v2-0001-Fix-the-name-collision-detection-in-MERGE-SPLIT-p.patchDownload
From eb21dcdba3263bc4702567b0af18e3ba32c4a280 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 17 May 2024 12:44:09 +0300
Subject: [PATCH v2 1/2] Fix the name collision detection in MERGE/SPLIT
partition operations
Both MERGE and SPLIT partition operations support the case when the name of the
new partition matches the name of the existing partition to be merged/split.
But the name collision detection doesn't always work as intended. The SPLIT
partition operation finds the namespace to search for an existing partition
without taking into account the parent's persistence. The MERGE partition
operation checks for the name collision with simple equal() on RangeVar's
simply ignoring the search_path.
This commit fixes this behavior as follows.
1. The SPLIT partition operation now finds the namespace to search for
an existing partition according to the parent's persistence.
2. The MERGE partition operation now checks for the name collision similarly
to the SPLIT partition operation using
RangeVarGetAndCheckCreationNamespace() and get_relname_relid().
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/86b4f1e3-0b5d-315c-9225-19860d64d685%40gmail.com
Author: Dmitry Koval, Alexander Korotkov
---
src/backend/commands/tablecmds.c | 62 +++++++++++++++----
src/test/regress/expected/partition_merge.out | 3 +-
src/test/regress/expected/partition_split.out | 8 +++
src/test/regress/sql/partition_merge.sql | 3 +-
src/test/regress/sql/partition_split.sql | 9 +++
5 files changed, 72 insertions(+), 13 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 313c782cae2..7a063ca8ae0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20409,6 +20409,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
* against concurrent drop, and mark stmt->relation as
* RELPERSISTENCE_TEMP if a temporary namespace is selected.
*/
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
namespaceId =
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
@@ -20601,6 +20602,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -20617,13 +20620,48 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
mergingPartition = table_openrv(name, AccessExclusiveLock);
- /*
- * Checking that two partitions have the same name was before, in
- * function transformPartitionCmdForMerge().
- */
- if (equal(name, cmd->name))
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
{
- /* One new partition can have the same name as merged partition. */
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
char tmpRelName[NAMEDATALEN];
/* Generate temporary name. */
@@ -20635,7 +20673,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* in the future because we're going to eventually drop the
* existing partition anyway.
*/
- RenameRelationInternal(RelationGetRelid(mergingPartition),
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
tmpRelName, false, false);
/*
@@ -20644,10 +20682,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
CommandCounterIncrement();
}
-
- /* Store a next merging partition into the list. */
- mergingPartitionsList = lappend(mergingPartitionsList,
- mergingPartition);
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
}
/* Detach all merged partitions. */
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 6361732d104..9c67a4a8b15 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -214,7 +214,8 @@ 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;
+ALTER TABLE sales_range MERGE PARTITIONS
+ (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
select * from sales_others;
salesperson_id | salesperson_name | sales_amount | sales_date
----------------+------------------+--------------+------------
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 14c4f97c9ff..6369f06b841 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1547,6 +1547,14 @@ REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
DROP ROLE regress_partition_split_bob;
+-- Check that detection, that the new partition has the same name as one of
+-- the merged partitions, works correctly for temporary partitions
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
RESET search_path;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 5a741efa09b..56249732002 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -140,7 +140,8 @@ 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;
+ALTER TABLE sales_range MERGE PARTITIONS
+ (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
select * from sales_others;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 70d70499ec6..67ed274f529 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -931,6 +931,15 @@ REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
DROP ROLE regress_partition_split_bob;
+-- Check that detection, that the new partition has the same name as one of
+-- the merged partitions, works correctly for temporary partitions
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
RESET search_path;
--
--
2.39.3 (Apple Git-145)
v2-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchapplication/octet-stream; name=v2-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchDownload
From a544336aabe5daee7e2124927de017644a01bc32 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 17 May 2024 12:56:46 +0300
Subject: [PATCH v2 2/2] Don't copy extended statistics during MERGE/SPLIT
partition operations
When MERGE/SPLIT created new partitions, it was cloning the extended
statistics of the parent table.
However, extended stats on partitioned tables are not analgous to
indexes on partitioned tables (which exist only to create physical
indexes on child tables). Rather, extended stats on a parent 1) cause
extended stats to be collected and computed across the whole partition
heirarchy, and 2) do not cause extended stats to be computed for the
individual partitions.
"CREATE TABLE ... PARTITION OF" command doesn't copy extended
statistics. This commit makes createPartitionTable() behave
consistently.
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZiJW1g2nbQs9ekwK%40pryzbyj2023
Author: Alexander Korotkov, Justin Pryzby
---
doc/src/sgml/ref/alter_table.sgml | 9 +++++++--
src/backend/commands/tablecmds.c | 8 +++++---
2 files changed, 12 insertions(+), 5 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5d352abf991..c062a36880d 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1154,9 +1154,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partitions will be created the same as tables created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
New partitions will have the same table access method as the parent.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
@@ -1224,9 +1227,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partition will be created the same as a table created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
The new partition will have the same table access method as the parent.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7a063ca8ae0..7b6c69b7a52 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20269,7 +20269,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* (newPartName) like table (modelRel)
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
- * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
*
* Also, this function sets the new partition access method same as parent
* table access methods (similarly to CREATE TABLE ... PARTITION OF). It
@@ -20313,9 +20313,11 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
/*
* Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY);
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
--
2.39.3 (Apple Git-145)
Hi, Alexander:
On Fri, 17 May 2024 at 14:05, Alexander Korotkov <aekorotkov@gmail.com>
wrote:
On Tue, May 14, 2024 at 5:49 PM Justin Pryzby <pryzby@telsasoft.com>
wrote:On Thu, May 09, 2024 at 12:51:32AM +0300, Alexander Korotkov wrote:
However, parent's table extended statistics already covers all its
children.=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and inthe
catalog.
The right explanation is that extended stats on partitioned tables
are
not similar to indexes. Indexes on parent table are nothing other
than
a mechanism to create indexes on the child tables. That's not true
for
stats.
See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023Yes, I understand that parents pg_statistic entry with stainherit ==
true includes statistics for the children. I tried to express this by
word "covers". But you're right, this is the wrong explanation.Can I, please, ask you to revise the patch?
I tried to make this clear but it'd be nice if someone (Tomas/Alvaro?)
would check that this says what's wanted.Thank you!
I've assembled the patches with the pending fixes.
0001 – The patch by Dmitry Koval for fixing detection of name
collision in SPLIT partition operation. Also, I found that name
collision detection doesn't work well for MERGE partitions. I've
added fix for that to this patch as well.
0002 -– Patch for skipping copy of extended statistics. I would
appreciate more feedback about wording, but I'd like to get a correct
behavior into the source tree sooner. If the docs and/or comments
need further improvements, we can fix that later.I'm going to push both if no objections.
Thank you for working on this patch set!
Some minor things:
0001:
partition_split.sql
157 +-- Check that detection, that the new partition has the same name as
one of
158 +-- the merged partitions, works correctly for temporary partitions
Test for split with comment for merge. Maybe better something like:
"Split partition of a temporary table when one of the partitions after
split has the same name as the partition being split"
0002:
analgous -> analogous (maybe better using "like" instead of "analogous to")
heirarchy -> hierarchy
alter_table.sgml:
Maybe in documentation it's better not to provide reasoning, just state how
it works:
for consistency with <command>CREATE TABLE PARTITION OF</command> ->
similar to <command>CREATE TABLE PARTITION OF</command>
Regards,
Pavel Borisov
Hi, Pavel!
On Fri, May 17, 2024 at 2:02 PM Pavel Borisov <pashkin.elfe@gmail.com> wrote:
On Fri, 17 May 2024 at 14:05, Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Tue, May 14, 2024 at 5:49 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Thu, May 09, 2024 at 12:51:32AM +0300, Alexander Korotkov wrote:
However, parent's table extended statistics already covers all its
children.=> That's the wrong explanation. It's not that "stats on the parent
table cover its children". It's that there are two types of stats:
stats for the "table hierarchy" and stats for the individual table.
That's true for single-column stats as well as for extended stats.
In both cases, that's indicated by the inh flag in the code and in the
catalog.The right explanation is that extended stats on partitioned tables are
not similar to indexes. Indexes on parent table are nothing other than
a mechanism to create indexes on the child tables. That's not true for
stats.See also my prior messages
ZiJW1g2nbQs9ekwK@pryzbyj2023
Zi5Msg74C61DjJKW@pryzbyj2023Yes, I understand that parents pg_statistic entry with stainherit ==
true includes statistics for the children. I tried to express this by
word "covers". But you're right, this is the wrong explanation.Can I, please, ask you to revise the patch?
I tried to make this clear but it'd be nice if someone (Tomas/Alvaro?)
would check that this says what's wanted.Thank you!
I've assembled the patches with the pending fixes.
0001 – The patch by Dmitry Koval for fixing detection of name
collision in SPLIT partition operation. Also, I found that name
collision detection doesn't work well for MERGE partitions. I've
added fix for that to this patch as well.
0002 -– Patch for skipping copy of extended statistics. I would
appreciate more feedback about wording, but I'd like to get a correct
behavior into the source tree sooner. If the docs and/or comments
need further improvements, we can fix that later.I'm going to push both if no objections.
Thank you for working on this patch set!
Some minor things:
0001:
partition_split.sql
157 +-- Check that detection, that the new partition has the same name as one of
158 +-- the merged partitions, works correctly for temporary partitions
Test for split with comment for merge. Maybe better something like:
"Split partition of a temporary table when one of the partitions after split has the same name as the partition being split"
Thank you, fixed as proposed.
0002:
analgous -> analogous (maybe better using "like" instead of "analogous to")
heirarchy -> hierarchy
Changed "are not analgous to" to "don't behave like".
alter_table.sgml:
Maybe in documentation it's better not to provide reasoning, just state how it works:
for consistency with <command>CREATE TABLE PARTITION OF</command> -> similar to <command>CREATE TABLE PARTITION OF</command>
I'd like to keep this. This is the question, which should naturally
arise when you read: "Why this is not just INCLUDING ALL?"
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v3-0001-Fix-the-name-collision-detection-in-MERGE-SPLIT-p.patchapplication/octet-stream; name=v3-0001-Fix-the-name-collision-detection-in-MERGE-SPLIT-p.patchDownload
From 6a6452a1b290edfe6da91617e4bb7ec827774ca1 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 17 May 2024 12:44:09 +0300
Subject: [PATCH v3 1/2] Fix the name collision detection in MERGE/SPLIT
partition operations
Both MERGE and SPLIT partition operations support the case when the name of the
new partition matches the name of the existing partition to be merged/split.
But the name collision detection doesn't always work as intended. The SPLIT
partition operation finds the namespace to search for an existing partition
without taking into account the parent's persistence. The MERGE partition
operation checks for the name collision with simple equal() on RangeVar's
simply ignoring the search_path.
This commit fixes this behavior as follows.
1. The SPLIT partition operation now finds the namespace to search for
an existing partition according to the parent's persistence.
2. The MERGE partition operation now checks for the name collision similarly
to the SPLIT partition operation using
RangeVarGetAndCheckCreationNamespace() and get_relname_relid().
Reported-by: Alexander Lakhin
Discussion: https://postgr.es/m/86b4f1e3-0b5d-315c-9225-19860d64d685%40gmail.com
Author: Dmitry Koval, Alexander Korotkov
---
src/backend/commands/tablecmds.c | 62 +++++++++++++++----
src/test/regress/expected/partition_merge.out | 3 +-
src/test/regress/expected/partition_split.out | 8 +++
src/test/regress/sql/partition_merge.sql | 3 +-
src/test/regress/sql/partition_split.sql | 9 +++
5 files changed, 72 insertions(+), 13 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 313c782cae2..7a063ca8ae0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20409,6 +20409,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
* against concurrent drop, and mark stmt->relation as
* RELPERSISTENCE_TEMP if a temporary namespace is selected.
*/
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
namespaceId =
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
@@ -20601,6 +20602,8 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ListCell *listptr;
List *mergingPartitionsList = NIL;
Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
/*
* Lock all merged partitions, check them and create list with partitions
@@ -20617,13 +20620,48 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
mergingPartition = table_openrv(name, AccessExclusiveLock);
- /*
- * Checking that two partitions have the same name was before, in
- * function transformPartitionCmdForMerge().
- */
- if (equal(name, cmd->name))
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
{
- /* One new partition can have the same name as merged partition. */
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
char tmpRelName[NAMEDATALEN];
/* Generate temporary name. */
@@ -20635,7 +20673,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* in the future because we're going to eventually drop the
* existing partition anyway.
*/
- RenameRelationInternal(RelationGetRelid(mergingPartition),
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
tmpRelName, false, false);
/*
@@ -20644,10 +20682,12 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
CommandCounterIncrement();
}
-
- /* Store a next merging partition into the list. */
- mergingPartitionsList = lappend(mergingPartitionsList,
- mergingPartition);
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
}
/* Detach all merged partitions. */
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 6361732d104..9c67a4a8b15 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -214,7 +214,8 @@ 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;
+ALTER TABLE sales_range MERGE PARTITIONS
+ (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
select * from sales_others;
salesperson_id | salesperson_name | sales_amount | sales_date
----------------+------------------+--------------+------------
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 14c4f97c9ff..d08eb4770ba 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1547,6 +1547,14 @@ REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
RESET search_path;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 5a741efa09b..56249732002 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -140,7 +140,8 @@ 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;
+ALTER TABLE sales_range MERGE PARTITIONS
+ (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
select * from sales_others;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 70d70499ec6..d9e2359cb76 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -931,6 +931,15 @@ REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
RESET search_path;
--
--
2.39.3 (Apple Git-145)
v3-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchapplication/octet-stream; name=v3-0002-Don-t-copy-extended-statistics-during-MERGE-SPLIT.patchDownload
From dc8c132f1a0d38e8535f2d0d05dcc5b33527f5af Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Fri, 17 May 2024 12:56:46 +0300
Subject: [PATCH v3 2/2] Don't copy extended statistics during MERGE/SPLIT
partition operations
When MERGE/SPLIT created new partitions, it was cloning the extended
statistics of the parent table.
However, extended stats on partitioned tables don't behave like
indexes on partitioned tables (which exist only to create physical
indexes on child tables). Rather, extended stats on a parent 1) cause
extended stats to be collected and computed across the whole partition
hierarchy, and 2) do not cause extended stats to be computed for the
individual partitions.
"CREATE TABLE ... PARTITION OF" command doesn't copy extended
statistics. This commit makes createPartitionTable() behave
consistently.
Reported-by: Justin Pryzby
Discussion: https://postgr.es/m/ZiJW1g2nbQs9ekwK%40pryzbyj2023
Author: Alexander Korotkov, Justin Pryzby
---
doc/src/sgml/ref/alter_table.sgml | 9 +++++++--
src/backend/commands/tablecmds.c | 8 +++++---
2 files changed, 12 insertions(+), 5 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5d352abf991..c062a36880d 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1154,9 +1154,12 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partitions will be created the same as tables created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
New partitions will have the same table access method as the parent.
If the parent table is persistent then new partitions are created
persistent. If the parent table is temporary then new partitions
@@ -1224,9 +1227,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>
<para>
The new partition will be created the same as a table created with the
- SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)</literal>.
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
The indexes and identity are created later, after moving the data
into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
The new partition will have the same table access method as the parent.
If the parent table is persistent then the new partition is created
persistent. If the parent table is temporary then the new partition
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7a063ca8ae0..7b6c69b7a52 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20269,7 +20269,7 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* (newPartName) like table (modelRel)
*
* Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
- * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY)
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
*
* Also, this function sets the new partition access method same as parent
* table access methods (similarly to CREATE TABLE ... PARTITION OF). It
@@ -20313,9 +20313,11 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
/*
* Indexes will be inherited on "attach new partitions" stage, after data
- * moving.
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
*/
- tlc->options = CREATE_TABLE_LIKE_ALL & ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY);
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
--
2.39.3 (Apple Git-145)
The partition_split test has unstable results, as shown at [1]https://buildfarm.postgresql.org/cgi-bin/show_log.pl?nm=jackdaw&dt=2024-05-24%2015%3A58%3A17.
I suggest adding "ORDER BY conname" to the two queries shown
to fail there. Better look at other queries in the test for
possible similar problems, too.
regards, tom lane
[1]: https://buildfarm.postgresql.org/cgi-bin/show_log.pl?nm=jackdaw&dt=2024-05-24%2015%3A58%3A17
Hello,
24.05.2024 22:29, Tom Lane wrote:
The partition_split test has unstable results, as shown at [1].
I suggest adding "ORDER BY conname" to the two queries shown
to fail there. Better look at other queries in the test for
possible similar problems, too.
Yes, I've just reproduced it on an aarch64 device as follows:
echo "autovacuum_naptime = 1
autovacuum_vacuum_threshold = 1
autovacuum_analyze_threshold = 1
" > ~/temp.config
TEMP_CONFIG=~/temp.config TESTS="$(printf 'partition_split %.0s' `seq 100`)" make -s check-tests
...
ok 80 - partition_split 749 ms
not ok 81 - partition_split 728 ms
ok 82 - partition_split 732 ms
$ cat src/test/regress/regression.diffs
diff -U3 .../src/test/regress/expected/partition_split.out .../src/test/regress/results/partition_split.out
--- .../src/test/regress/expected/partition_split.out 2024-05-15 17:15:57.171999830 +0000
+++ .../src/test/regress/results/partition_split.out 2024-05-24 19:28:37.329999749 +0000
@@ -625,8 +625,8 @@
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid =
'sales_feb_mar_apr2022'::regclass::oid;
pg_get_constraintdef | conname | conkey
---------------------------------------------------------------------+---------------------------------+--------
- CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
(2 rows)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
Best regards,
Alexander
On Fri, May 24, 2024 at 11:00 PM Alexander Lakhin <exclusion@gmail.com> wrote:
24.05.2024 22:29, Tom Lane wrote:
The partition_split test has unstable results, as shown at [1].
I suggest adding "ORDER BY conname" to the two queries shown
to fail there. Better look at other queries in the test for
possible similar problems, too.Yes, I've just reproduced it on an aarch64 device as follows:
echo "autovacuum_naptime = 1
autovacuum_vacuum_threshold = 1
autovacuum_analyze_threshold = 1
" > ~/temp.config
TEMP_CONFIG=~/temp.config TESTS="$(printf 'partition_split %.0s' `seq 100`)" make -s check-tests
...
ok 80 - partition_split 749 ms
not ok 81 - partition_split 728 ms
ok 82 - partition_split 732 ms$ cat src/test/regress/regression.diffs diff -U3 .../src/test/regress/expected/partition_split.out .../src/test/regress/results/partition_split.out --- .../src/test/regress/expected/partition_split.out 2024-05-15 17:15:57.171999830 +0000 +++ .../src/test/regress/results/partition_split.out 2024-05-24 19:28:37.329999749 +0000 @@ -625,8 +625,8 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid; pg_get_constraintdef | conname | conkey ---------------------------------------------------------------------+---------------------------------+-------- - CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2} FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1} + CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2} (2 rows)ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
Tom, Alexander, thank you for spotting this.
I'm going to care about it later today.
------
Regards,
Alexander Korotkov
Supabase
On Fri, May 03, 2024 at 04:32:25PM +0300, Alexander Korotkov wrote:
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
Note that the error that led to "EXCLUDING IDENTITY" is being discused
over here:
/messages/by-id/3b8a9dc1-bbc7-0ef5-6863-c432afac7d59@gmail.comIt's possible that once that's addressed, the exclusion should be
removed here, too.+1
Can EXCLUDING IDENTITY be removed now ?
I wasn't able to find why it was needed - at one point, I think there
was a test case that threw an error, but now when I remove the EXCLUDE,
nothing goes wrong.
--
Justin
On Sat, May 25, 2024 at 8:53 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
On Fri, May 03, 2024 at 04:32:25PM +0300, Alexander Korotkov wrote:
On Fri, May 3, 2024 at 4:23 PM Justin Pryzby <pryzby@telsasoft.com> wrote:
Note that the error that led to "EXCLUDING IDENTITY" is being discused
over here:
/messages/by-id/3b8a9dc1-bbc7-0ef5-6863-c432afac7d59@gmail.comIt's possible that once that's addressed, the exclusion should be
removed here, too.+1
Can EXCLUDING IDENTITY be removed now ?
I wasn't able to find why it was needed - at one point, I think there
was a test case that threw an error, but now when I remove the EXCLUDE,
nothing goes wrong.
Yes, it was broken before [1][2], but now it seems to work. At the
same time, I'm not sure if we need to remove the EXCLUDE now.
IDENTITY is anyway successfully created when the new partition gets
attached.
Links.
1. /messages/by-id/171085360143.2046436.7217841141682511557.pgcf@coridan.postgresql.org
2. /messages/by-id/ZiGH0xc1lxJ71ZfB@pryzbyj2023
------
Regards,
Alexander Korotkov
Supabase
On Sat, May 25, 2024 at 3:53 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Fri, May 24, 2024 at 11:00 PM Alexander Lakhin <exclusion@gmail.com> wrote:
24.05.2024 22:29, Tom Lane wrote:
The partition_split test has unstable results, as shown at [1].
I suggest adding "ORDER BY conname" to the two queries shown
to fail there. Better look at other queries in the test for
possible similar problems, too.Yes, I've just reproduced it on an aarch64 device as follows:
echo "autovacuum_naptime = 1
autovacuum_vacuum_threshold = 1
autovacuum_analyze_threshold = 1
" > ~/temp.config
TEMP_CONFIG=~/temp.config TESTS="$(printf 'partition_split %.0s' `seq 100`)" make -s check-tests
...
ok 80 - partition_split 749 ms
not ok 81 - partition_split 728 ms
ok 82 - partition_split 732 ms$ cat src/test/regress/regression.diffs diff -U3 .../src/test/regress/expected/partition_split.out .../src/test/regress/results/partition_split.out --- .../src/test/regress/expected/partition_split.out 2024-05-15 17:15:57.171999830 +0000 +++ .../src/test/regress/results/partition_split.out 2024-05-24 19:28:37.329999749 +0000 @@ -625,8 +625,8 @@ SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid; pg_get_constraintdef | conname | conkey ---------------------------------------------------------------------+---------------------------------+-------- - CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2} FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1} + CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2} (2 rows)ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
Tom, Alexander, thank you for spotting this.
I'm going to care about it later today.
ORDER BY is added in d53a4286d7 in these queries altogether with other
catalog queries with potentially unstable result.
------
Regards,
Alexander Korotkov
Supabase
On Sun, Apr 07, 2024 at 01:22:51AM +0300, Alexander Korotkov wrote:
I've pushed 0001 and 0002
The partition MERGE (1adf16b8f) and SPLIT (87c21bb94) v17 patches introduced
createPartitionTable() with this code:
createStmt->relation = newPartName;
...
wrapper->utilityStmt = (Node *) createStmt;
...
ProcessUtility(wrapper,
...
newRel = table_openrv(newPartName, NoLock);
This breaks from the CVE-2014-0062 (commit 5f17304) principle of not repeating
name lookups. The attached demo uses this defect to make one partition have
two parents.
Attachments:
repro-merge-partition-race-v0.patchtext/plain; charset=us-asciiDownload
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index ae2efdc..654b502 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -3495,7 +3495,11 @@ StorePartitionBound(Relation rel, Relation parent, PartitionBoundSpec *bound)
elog(ERROR, "cache lookup failed for relation %u",
RelationGetRelid(rel));
-#ifdef USE_ASSERT_CHECKING
+ /*
+ * Assertion fails during partition getting multiple parents. Disable the
+ * assertion, to see what non-assert builds experience.
+ */
+#if 0
{
Form_pg_class classForm;
bool isnull;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 8fcb188..48207f9 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -95,6 +95,7 @@
#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/fmgroids.h"
+#include "utils/injection_point.h"
#include "utils/inval.h"
#include "utils/lsyscache.h"
#include "utils/memutils.h"
@@ -15825,7 +15826,11 @@ MergeAttributesIntoExisting(Relation child_rel, Relation parent_rel, bool ispart
*/
if (parent_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
{
- Assert(child_att->attinhcount == 1);
+ /*
+ * Assertion fails during partition getting multiple parents.
+ * Disable, to see what non-assert builds experience.
+ */
+ /* Assert(child_att->attinhcount == 1); */
child_att->attislocal = false;
}
@@ -20388,7 +20393,14 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ INJECTION_POINT("merge-after-create");
+ /*
+ * For testing, switch to taking a lock. This solves two problems.
+ * First, it gets an AcceptInvalidationMessages(), so we actually
+ * invalidate the search path. Second, it avoids an assertion failure
+ * from our lack of lock, so we see what non-assert builds experience.
+ */
+ newRel = table_openrv(newPartName, AccessExclusiveLock);
/*
* We intended to create the partition with the same persistence as the
diff --git a/src/test/modules/injection_points/Makefile b/src/test/modules/injection_points/Makefile
index 2ffd2f7..9af45bf 100644
--- a/src/test/modules/injection_points/Makefile
+++ b/src/test/modules/injection_points/Makefile
@@ -9,7 +9,7 @@ PGFILEDESC = "injection_points - facility for injection points"
REGRESS = injection_points
REGRESS_OPTS = --dlpath=$(top_builddir)/src/test/regress
-ISOLATION = inplace
+ISOLATION = inplace merge
# The injection points are cluster-wide, so disable installcheck
NO_INSTALLCHECK = 1
diff --git a/src/test/modules/injection_points/expected/merge.out b/src/test/modules/injection_points/expected/merge.out
new file mode 100644
index 0000000..04920e7
--- /dev/null
+++ b/src/test/modules/injection_points/expected/merge.out
@@ -0,0 +1,60 @@
+Parsed test spec with 3 sessions
+
+starting permutation: merge1 ct2 detach3
+injection_points_attach
+-----------------------
+
+(1 row)
+
+step merge1:
+ SET search_path = target;
+ ALTER TABLE parted MERGE PARTITIONS (part1, part3) INTO part_all;
+ -- only one of *parted should have rows, but both do
+ SELECT a AS new_target_parted FROM target.parted ORDER BY 1;
+ SELECT a AS old_target_parted FROM old_target.parted ORDER BY 1;
+ SELECT a AS new_target_part_all FROM target.part_all ORDER BY 1;
+ SELECT a AS old_target_part_all FROM old_target.part_all ORDER BY 1;
+ <waiting ...>
+step ct2:
+ ALTER SCHEMA target RENAME TO old_target;
+ CREATE SCHEMA target
+ CREATE TABLE parted (a int) partition by list (a)
+ CREATE TABLE part_all PARTITION OF parted FOR VALUES IN (1, 2, 3, 4)
+
+step detach3:
+ SELECT injection_points_detach('merge-after-create');
+ SELECT injection_points_wakeup('merge-after-create');
+
+injection_points_detach
+-----------------------
+
+(1 row)
+
+injection_points_wakeup
+-----------------------
+
+(1 row)
+
+step merge1: <... completed>
+new_target_parted
+-----------------
+ 1
+ 3
+(2 rows)
+
+old_target_parted
+-----------------
+ 1
+ 3
+(2 rows)
+
+new_target_part_all
+-------------------
+ 1
+ 3
+(2 rows)
+
+old_target_part_all
+-------------------
+(0 rows)
+
diff --git a/src/test/modules/injection_points/specs/merge.spec b/src/test/modules/injection_points/specs/merge.spec
new file mode 100644
index 0000000..63bcd2b
--- /dev/null
+++ b/src/test/modules/injection_points/specs/merge.spec
@@ -0,0 +1,51 @@
+setup
+{
+ CREATE EXTENSION injection_points;
+ CREATE SCHEMA target
+ CREATE TABLE parted (a int) partition by list (a)
+ CREATE TABLE part1 PARTITION OF parted FOR VALUES IN (1, 2)
+ CREATE TABLE part3 PARTITION OF parted FOR VALUES IN (3, 4);
+ INSERT INTO target.parted VALUES (1),(3);
+}
+teardown
+{
+ DROP SCHEMA target, old_target CASCADE;
+ DROP EXTENSION injection_points;
+}
+
+# MERGE PARTITIONS
+session s1
+setup {
+ SELECT injection_points_set_local();
+ SELECT injection_points_attach('merge-after-create', 'wait');
+}
+step merge1 {
+ SET search_path = target;
+ ALTER TABLE parted MERGE PARTITIONS (part1, part3) INTO part_all;
+ -- only one of *parted should have rows, but both do
+ SELECT a AS new_target_parted FROM target.parted ORDER BY 1;
+ SELECT a AS old_target_parted FROM old_target.parted ORDER BY 1;
+ SELECT a AS new_target_part_all FROM target.part_all ORDER BY 1;
+ SELECT a AS old_target_part_all FROM old_target.part_all ORDER BY 1;
+}
+
+
+# inject another table via ALTER SCHEMA RENAME
+session s2
+step ct2 {
+ ALTER SCHEMA target RENAME TO old_target;
+ CREATE SCHEMA target
+ CREATE TABLE parted (a int) partition by list (a)
+ CREATE TABLE part_all PARTITION OF parted FOR VALUES IN (1, 2, 3, 4)
+}
+
+
+# injection release
+session s3
+step detach3 {
+ SELECT injection_points_detach('merge-after-create');
+ SELECT injection_points_wakeup('merge-after-create');
+}
+
+
+permutation merge1(detach3) ct2 detach3
On Thu, Aug 8, 2024 at 8:14 PM Noah Misch <noah@leadboat.com> wrote:
On Sun, Apr 07, 2024 at 01:22:51AM +0300, Alexander Korotkov wrote:
I've pushed 0001 and 0002
The partition MERGE (1adf16b8f) and SPLIT (87c21bb94) v17 patches introduced
createPartitionTable() with this code:createStmt->relation = newPartName;
...
wrapper->utilityStmt = (Node *) createStmt;
...
ProcessUtility(wrapper,
...
newRel = table_openrv(newPartName, NoLock);This breaks from the CVE-2014-0062 (commit 5f17304) principle of not repeating
name lookups. The attached demo uses this defect to make one partition have
two parents.
Thank you for a valuable report. I will dig into and fix that.
------
Regards,
Alexander Korotkov
Supabase
This breaks from the CVE-2014-0062 (commit 5f17304) principle of not repeating
name lookups. The attached demo uses this defect to make one partition have
two parents.
Thank you very much for information (especially for the demo)!
I'm not sure that we can get the identifier of the newly created
partition from the ProcessUtility() function...
Maybe it would be enough to check that the new partition is located in
the namespace in which we created it (see attachment)?
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
namespace-check.difftext/plain; charset=UTF-8; name=namespace-check.diffDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 0b2a52463f..a1937d078b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20388,6 +20388,14 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
*/
newRel = table_openrv(newPartName, NoLock);
+ /* Check for case namespace was renamed during partition creation. */
+ if (RelationGetNamespace(newRel) != RelationGetNamespace(modelRel))
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create partition because namespace \"%s\" was changed to \"%s\"",
+ get_namespace_name(RelationGetNamespace(newRel)),
+ get_namespace_name(RelationGetNamespace(modelRel)))));
+
/*
* We intended to create the partition with the same persistence as the
* parent table, but we still need to recheck because that might be
On Fri, Aug 9, 2024 at 10:18 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
This breaks from the CVE-2014-0062 (commit 5f17304) principle of not repeating
name lookups. The attached demo uses this defect to make one partition have
two parents.Thank you very much for information (especially for the demo)!
I'm not sure that we can get the identifier of the newly created
partition from the ProcessUtility() function...
Maybe it would be enough to check that the new partition is located in
the namespace in which we created it (see attachment)?
The new partition doesn't necessarily get created in the same
namespace as parent partition. I think it would be better to somehow
open partition by its oid.
It would be quite unfortunate to replicate significant part of
ProcessUtilitySlow(). So, the question is how to get the oid of newly
created relation from ProcessUtility(). I don't like to change the
signature of ProcessUtility() especially as a part of backpatch. So,
I tried to fit this into existing parameters. Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v1-0001-Fix-createPartitionTable-security-issue.patchapplication/x-patch; name=v1-0001-Fix-createPartitionTable-security-issue.patchDownload
From 83b6d8e38d680daa952542f6ae4a41ae48491a62 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sat, 10 Aug 2024 16:19:28 +0300
Subject: [PATCH v1] Fix createPartitionTable() security issue
---
src/backend/commands/tablecmds.c | 6 ++++--
src/backend/tcop/utility.c | 2 ++
src/include/tcop/cmdtag.h | 3 +++
3 files changed, 9 insertions(+), 2 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1f94f4fdbbc..c64b4953da8 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20329,6 +20329,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
TableLikeClause *tlc;
PlannedStmt *wrapper;
Relation newRel;
+ QueryCompletion qc;
/* If existing rel is temp, it must belong to this session */
if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
@@ -20373,6 +20374,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
wrapper->stmt_location = context->pstmt->stmt_location;
wrapper->stmt_len = context->pstmt->stmt_len;
+ qc.commandTag = CMDTAG_UNKNOWN;
ProcessUtility(wrapper,
context->queryString,
false,
@@ -20380,13 +20382,13 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
NULL,
NULL,
None_Receiver,
- NULL);
+ &qc);
/*
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(qc.tableAddress.objectId, NoLock);
/*
* We intended to create the partition with the same persistence as the
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index b2ea8125c92..e8a83e0c569 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -1165,6 +1165,8 @@ ProcessUtilitySlow(ParseState *pstate,
RELKIND_RELATION,
InvalidOid, NULL,
queryString);
+ if (qc)
+ qc->tableAddress = address;
EventTriggerCollectSimpleCommand(address,
secondaryObject,
stmt);
diff --git a/src/include/tcop/cmdtag.h b/src/include/tcop/cmdtag.h
index 23c99d7eca6..a964a8c0cb7 100644
--- a/src/include/tcop/cmdtag.h
+++ b/src/include/tcop/cmdtag.h
@@ -13,6 +13,8 @@
#ifndef CMDTAG_H
#define CMDTAG_H
+#include "catalog/objectaddress.h"
+
/* buffer size required for command completion tags */
#define COMPLETION_TAG_BUFSIZE 64
@@ -29,6 +31,7 @@ typedef enum CommandTag
typedef struct QueryCompletion
{
CommandTag commandTag;
+ ObjectAddress tableAddress;
uint64 nprocessed;
} QueryCompletion;
--
2.39.3 (Apple Git-146)
Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?
I agree, returning the oid of the newly created relation is the best way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Sat, Aug 10, 2024 at 6:57 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?I agree, returning the oid of the newly created relation is the best way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).
Thank you for your feedback. Although, I decided QueryCompletion is
not a good place for this new field. It looks more appropriate to
place it to TableLikeClause, which already contains one relation oid
inside. The revised patch is attached.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v2-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchapplication/octet-stream; name=v2-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchDownload
From 448776815764803e5c25288b43011b3fcce76c99 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sat, 10 Aug 2024 16:19:28 +0300
Subject: [PATCH v2] Avoid repeated table name lookups in
createPartitionTable()
Currently, createPartitionTable() opens newly created table using its name.
This approach is prone to privilege escalation attack, because we might end
up opening another table than we just created.
This commit address the issue above by opening newly created table by its
oid. It appears to be tricky to get a relation oid out of ProcessUtility().
We have to extend TableLikeClause with new newRelationOid field, which is
filled within ProcessUtility() to be further accessed by caller.
Security: CVE-2014-0062
Reported-by: Noah Misch
Discussion: https://postgr.es/m/20240808171351.a9.nmisch%40google.com
Reviewed-by: Dmitry Koval
---
src/backend/commands/tablecmds.c | 2 +-
src/backend/tcop/utility.c | 6 ++++++
src/include/nodes/parsenodes.h | 1 +
3 files changed, 8 insertions(+), 1 deletion(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7a36db6af6d..8719b4bf291 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20403,7 +20403,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(tlc->newRelationOid, NoLock);
/*
* We intended to create the partition with the same persistence as the
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index b2ea8125c92..26a30bfdd56 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -1225,6 +1225,12 @@ ProcessUtilitySlow(ParseState *pstate,
morestmts = expandTableLikeClause(table_rv, like);
stmts = list_concat(morestmts, stmts);
+
+ /*
+ * Put the Oid of newly created relation to the
+ * TableLikeClause, so caller might use it.
+ */
+ like->newRelationOid = address.objectId;
}
else
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e5..577c4bfef76 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -754,6 +754,7 @@ typedef struct TableLikeClause
RangeVar *relation;
bits32 options; /* OR of TableLikeOption flags */
Oid relationOid; /* If table has been looked up, its OID */
+ Oid newRelationOid; /* OID of newly created table */
} TableLikeClause;
typedef enum TableLikeOption
--
2.39.3 (Apple Git-146)
Hi, Alexander!
On Mon, 19 Aug 2024 at 02:24, Alexander Korotkov <aekorotkov@gmail.com>
wrote:
On Sat, Aug 10, 2024 at 6:57 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?I agree, returning the oid of the newly created relation is the best way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).Thank you for your feedback. Although, I decided QueryCompletion is
not a good place for this new field. It looks more appropriate to
place it to TableLikeClause, which already contains one relation oid
inside. The revised patch is attached.
I've looked at the patch v2. Remembering the OID of a relation newly
created with LIKE in TableLikeClause seems good to me.
Check-world passes sucessfully.
Shouldn't we also modify the TableLikeClause node in gram.y accordingly?
For the comments:
Put the Oid -> Store the OID
so caller might use it -> for the caller to use it.
(Maybe also caller -> table create function)
Regards,
Pavel Borisov
Supabase
Hi, Pavel!
On Wed, Aug 21, 2024 at 1:48 PM Pavel Borisov <pashkin.elfe@gmail.com> wrote:
On Mon, 19 Aug 2024 at 02:24, Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Sat, Aug 10, 2024 at 6:57 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?I agree, returning the oid of the newly created relation is the best way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).Thank you for your feedback. Although, I decided QueryCompletion is
not a good place for this new field. It looks more appropriate to
place it to TableLikeClause, which already contains one relation oid
inside. The revised patch is attached.I've looked at the patch v2. Remembering the OID of a relation newly created with LIKE in TableLikeClause seems good to me.
Check-world passes sucessfully.
Thank you.
Shouldn't we also modify the TableLikeClause node in gram.y accordingly?
On the one hand, makeNode() uses palloc0() and initializes all fields
with zero anyway. On the other hand, there is already assignment of
relationOid. So, yes I'll add assignment of newRelationOid for the
sake of uniformity.
For the comments:
Put the Oid -> Store the OID
so caller might use it -> for the caller to use it.
Accepted.
(Maybe also caller -> table create function)
I'll prefer to leave it "caller" as more generic term, which could
also fit potential future usages.
The revised patch is attached. I'm going to push it if no objections.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v3-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchapplication/octet-stream; name=v3-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchDownload
From 32d2fb0a65663204e2d8f8efb392063afa174d85 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sat, 10 Aug 2024 16:19:28 +0300
Subject: [PATCH v3] Avoid repeated table name lookups in
createPartitionTable()
Currently, createPartitionTable() opens newly created table using its name.
This approach is prone to privilege escalation attack, because we might end
up opening another table than we just created.
This commit address the issue above by opening newly created table by its
oid. It appears to be tricky to get a relation oid out of ProcessUtility().
We have to extend TableLikeClause with new newRelationOid field, which is
filled within ProcessUtility() to be further accessed by caller.
Security: CVE-2014-0062
Reported-by: Noah Misch
Discussion: https://postgr.es/m/20240808171351.a9.nmisch%40google.com
Reviewed-by: Dmitry Koval
---
src/backend/commands/tablecmds.c | 3 ++-
src/backend/parser/gram.y | 1 +
src/backend/tcop/utility.c | 6 ++++++
src/include/nodes/parsenodes.h | 1 +
4 files changed, 10 insertions(+), 1 deletion(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dfba5f357b8..bcc2d9ae0b3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20381,6 +20381,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
tlc->options = CREATE_TABLE_LIKE_ALL &
~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
+ tlc->newRelationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
/* Need to make a wrapper PlannedStmt. */
@@ -20404,7 +20405,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(tlc->newRelationOid, NoLock);
/*
* We intended to create the partition with the same persistence as the
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3f25582c38..b7d98eb9f02 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -4138,6 +4138,7 @@ TableLikeClause:
n->relation = $2;
n->options = $3;
n->relationOid = InvalidOid;
+ n->newRelationOid = InvalidOid;
$$ = (Node *) n;
}
;
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index b2ea8125c92..29868ed04c5 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -1225,6 +1225,12 @@ ProcessUtilitySlow(ParseState *pstate,
morestmts = expandTableLikeClause(table_rv, like);
stmts = list_concat(morestmts, stmts);
+
+ /*
+ * Store the Oid of newly created relation to the
+ * TableLikeClause for the caller to use it.
+ */
+ like->newRelationOid = address.objectId;
}
else
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e5..577c4bfef76 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -754,6 +754,7 @@ typedef struct TableLikeClause
RangeVar *relation;
bits32 options; /* OR of TableLikeOption flags */
Oid relationOid; /* If table has been looked up, its OID */
+ Oid newRelationOid; /* OID of newly created table */
} TableLikeClause;
typedef enum TableLikeOption
--
2.39.3 (Apple Git-146)
Hi, Alexander!
On Wed, 21 Aug 2024 at 15:55, Alexander Korotkov <aekorotkov@gmail.com>
wrote:
Hi, Pavel!
On Wed, Aug 21, 2024 at 1:48 PM Pavel Borisov <pashkin.elfe@gmail.com>
wrote:On Mon, 19 Aug 2024 at 02:24, Alexander Korotkov <aekorotkov@gmail.com>
wrote:
On Sat, Aug 10, 2024 at 6:57 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:
Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?I agree, returning the oid of the newly created relation is the best
way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).Thank you for your feedback. Although, I decided QueryCompletion is
not a good place for this new field. It looks more appropriate to
place it to TableLikeClause, which already contains one relation oid
inside. The revised patch is attached.I've looked at the patch v2. Remembering the OID of a relation newly
created with LIKE in TableLikeClause seems good to me.
Check-world passes sucessfully.
Thank you.
Shouldn't we also modify the TableLikeClause node in gram.y accordingly?
On the one hand, makeNode() uses palloc0() and initializes all fields
with zero anyway. On the other hand, there is already assignment of
relationOid. So, yes I'll add assignment of newRelationOid for the
sake of uniformity.For the comments:
Put the Oid -> Store the OID
so caller might use it -> for the caller to use it.
Accepted.
(Maybe also caller -> table create function)
I'll prefer to leave it "caller" as more generic term, which could
also fit potential future usages.The revised patch is attached. I'm going to push it if no objections.
Looked at v3
All good except the patch has "Oid" and "OID" in two comments. I suppose
"OID" is preferred elsewhere in the PG comments.
Regards,
Pavel.
On Wed, Aug 21, 2024 at 3:06 PM Pavel Borisov <pashkin.elfe@gmail.com> wrote:
On Wed, 21 Aug 2024 at 15:55, Alexander Korotkov <aekorotkov@gmail.com> wrote:
Hi, Pavel!
On Wed, Aug 21, 2024 at 1:48 PM Pavel Borisov <pashkin.elfe@gmail.com> wrote:
On Mon, 19 Aug 2024 at 02:24, Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Sat, Aug 10, 2024 at 6:57 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Probably
QueryCompletion struct fits this purpose best from the existing
parameters. Attached draft patch implements returning oid of newly
created relation as part of QueryCompletion. Thoughts?I agree, returning the oid of the newly created relation is the best way
to solve the problem.
(Excuse me, I won't have access to a laptop for the next week - and
won't be able to look at the source code).Thank you for your feedback. Although, I decided QueryCompletion is
not a good place for this new field. It looks more appropriate to
place it to TableLikeClause, which already contains one relation oid
inside. The revised patch is attached.I've looked at the patch v2. Remembering the OID of a relation newly created with LIKE in TableLikeClause seems good to me.
Check-world passes sucessfully.Thank you.
Shouldn't we also modify the TableLikeClause node in gram.y accordingly?
On the one hand, makeNode() uses palloc0() and initializes all fields
with zero anyway. On the other hand, there is already assignment of
relationOid. So, yes I'll add assignment of newRelationOid for the
sake of uniformity.For the comments:
Put the Oid -> Store the OIDso caller might use it -> for the caller to use it.
Accepted.
(Maybe also caller -> table create function)
I'll prefer to leave it "caller" as more generic term, which could
also fit potential future usages.The revised patch is attached. I'm going to push it if no objections.
Looked at v3
All good except the patch has "Oid" and "OID" in two comments. I suppose "OID" is preferred elsewhere in the PG comments.
Correct, the same file contains "OID" multiple times. Revised version
is attached.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v4-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchapplication/octet-stream; name=v4-0001-Avoid-repeated-table-name-lookups-in-createPartit.patchDownload
From cc3992a9262b126bc16a2e9f620c41aedcf99cba Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sat, 10 Aug 2024 16:19:28 +0300
Subject: [PATCH v4] Avoid repeated table name lookups in
createPartitionTable()
Currently, createPartitionTable() opens newly created table using its name.
This approach is prone to privilege escalation attack, because we might end
up opening another table than we just created.
This commit address the issue above by opening newly created table by its
oid. It appears to be tricky to get a relation oid out of ProcessUtility().
We have to extend TableLikeClause with new newRelationOid field, which is
filled within ProcessUtility() to be further accessed by caller.
Security: CVE-2014-0062
Reported-by: Noah Misch
Discussion: https://postgr.es/m/20240808171351.a9.nmisch%40google.com
Reviewed-by: Dmitry Koval
---
src/backend/commands/tablecmds.c | 3 ++-
src/backend/parser/gram.y | 1 +
src/backend/tcop/utility.c | 6 ++++++
src/include/nodes/parsenodes.h | 1 +
4 files changed, 10 insertions(+), 1 deletion(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dfba5f357b8..bcc2d9ae0b3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20381,6 +20381,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
tlc->options = CREATE_TABLE_LIKE_ALL &
~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
tlc->relationOid = InvalidOid;
+ tlc->newRelationOid = InvalidOid;
createStmt->tableElts = lappend(createStmt->tableElts, tlc);
/* Need to make a wrapper PlannedStmt. */
@@ -20404,7 +20405,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(tlc->newRelationOid, NoLock);
/*
* We intended to create the partition with the same persistence as the
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3f25582c38..b7d98eb9f02 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -4138,6 +4138,7 @@ TableLikeClause:
n->relation = $2;
n->options = $3;
n->relationOid = InvalidOid;
+ n->newRelationOid = InvalidOid;
$$ = (Node *) n;
}
;
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index b2ea8125c92..b385175e7a2 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -1225,6 +1225,12 @@ ProcessUtilitySlow(ParseState *pstate,
morestmts = expandTableLikeClause(table_rv, like);
stmts = list_concat(morestmts, stmts);
+
+ /*
+ * Store the OID of newly created relation to the
+ * TableLikeClause for the caller to use it.
+ */
+ like->newRelationOid = address.objectId;
}
else
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e5..577c4bfef76 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -754,6 +754,7 @@ typedef struct TableLikeClause
RangeVar *relation;
bits32 options; /* OR of TableLikeOption flags */
Oid relationOid; /* If table has been looked up, its OID */
+ Oid newRelationOid; /* OID of newly created table */
} TableLikeClause;
typedef enum TableLikeOption
--
2.39.3 (Apple Git-146)
Hi,
In response to some concerns raised about this fix on the
pgsql-release list today, I spent some time investigating this patch.
Unfortunately, I think there are too many problems here to be
reasonably fixed before release, and I think all of SPLIT/MERGE
PARTITION needs to be reverted.
I focused my investigation on createPartitionTable(), which is a
helper for both SPLIT PARTITION and MERGE PARTITION, and it works by
consing up a CREATE TABLE AS statement and then feeding that back
through
ProcessUtility. I think it's bad design to use such a high-level
facility here; it is unlike what we do elsewhere in tablecmds.c and
opens us up to a variety of problems. The first thing that I
discovered is that this patch does not fix all of the repeated name
lookup problems. There is still this:
tlc->relation =
makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
RelationGetRelationName(modelRel), -1);
And also this:
createStmt->tablespacename =
get_tablespace_name(modelRel->rd_rel->reltablespace);
In both cases, we do a reverse lookup on an OID to get a name which
the CREATE TABLE code will later turn back into an OID. If we don't
get the same value, that's at least a bug and probably a security
vulnerability, and there is no way to be certain that we will get the
same value. The only remedy is to not repeat the lookup in the first
place.
Then I got to looking at this:
tlc->options = CREATE_TABLE_LIKE_ALL &
~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY |
CREATE_TABLE_LIKE_STATISTICS);
It's not obvious at first glance that there is a critical problem
here, but there are reasons to be nervous. We're deploying a lot of
machinery here to copy a lot of stuff and, while that's efficient from
a coding perspective, it means that stuff you might not expect can
just kind of happen. For instance:
robert.haas=# \d+
List of relations
Schema | Name | Type | Owner | Persistence |
Access method | Size | Description
--------+------+-------------------+-------------+-------------+---------------+------------+-------------
public | foo | partitioned table | robert.haas | permanent |
| 0 bytes |
public | foo1 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo2 | table | bob | permanent | heap
| 8192 bytes |
(3 rows)
robert.haas=# alter table foo split partition foo2 into (partition
foo3 for values from (10) to (15), partition foo4 for values from (15)
to (20));
ALTER TABLE
robert.haas=# \d+
List of relations
Schema | Name | Type | Owner | Persistence |
Access method | Size | Description
--------+------+-------------------+-------------+-------------+---------------+------------+-------------
public | foo | partitioned table | robert.haas | permanent |
| 0 bytes |
public | foo1 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo3 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo4 | table | robert.haas | permanent | heap
| 8192 bytes |
(4 rows)
I've split a partition owned by bob into two partitions owned by
robert.haas. That's rather surprising. It doesn't work to split a
partition that I don't own (and thus gain access to it) but if the
superuser splits a non-superuser's partition, the superuser ends
upowning the new partitions. I don't know if that's a vulnerability or
just unexpected. However, then I found this, which I'm pretty well
certain is a vulnerability:
robert.haas=# set role bob;
SET
robert.haas=> create table foo (a int, b text) partition by range (a);
CREATE TABLE
robert.haas=> create table foo1 partition of foo for values from (0) to (10);
CREATE TABLE
robert.haas=> create table foo2 partition of foo for values from (10) to (20);
CREATE TABLE
robert.haas=> insert into foo values (11, 'carrots'), (16, 'pineapple');
INSERT 0 2
robert.haas=> create or replace function run_me(integer) returns
integer as $$begin raise notice 'you are running me as %',
current_user; return $1; end$$ language plpgsql immutable;
CREATE FUNCTION
robert.haas=> create index on foo (run_me(a));
NOTICE: you are running me as bob
NOTICE: you are running me as bob
CREATE INDEX
robert.haas=> reset role;
RESET
robert.haas=# alter table foo split partition foo2 into (partition
foo3 for values from (10) to (15), partition foo4 for values from (15)
to (20));
NOTICE: you are running me as robert.haas
NOTICE: you are running me as robert.haas
ALTER TABLE
I think it is very unlikely that the problems mentioned above are the
only ones. They're just what I found in an hour or two of testing.
Even if they were, we're probably too close to release to be rushing
out last minute fixes to multiple unanticipated security problems. But
because of the design that was chosen here, I think there is probably
more stuff here that is not right, some of which is security relevant
and some of which is just a question of whether we're really getting
the behavior that we want. And I don't think we can fix all that
without either a very large number of grotty hacks similar to the one
installed by 04158e7fa37c2dda9c3421ca922d02807b86df19, or a complete
redesign of the feature. I believe the latter is probably a wiser
course of action.
...Robert
On 8/22/24 12:33 PM, Robert Haas wrote:
I think it is very unlikely that the problems mentioned above are the
only ones. They're just what I found in an hour or two of testing.
Even if they were, we're probably too close to release to be rushing
out last minute fixes to multiple unanticipated security problems. But
because of the design that was chosen here, I think there is probably
more stuff here that is not right, some of which is security relevant
and some of which is just a question of whether we're really getting
the behavior that we want. And I don't think we can fix all that
without either a very large number of grotty hacks similar to the one
installed by 04158e7fa37c2dda9c3421ca922d02807b86df19, or a complete
redesign of the feature. I believe the latter is probably a wiser
course of action.
I can't comment on the design as much, but from a release standpoint,
but security concerns this close to the RC/GA period do concern me.
Applying the lessons from PG15 + SQL/JSON where we (and I'll own that I
was the one who pushed hard to include it) let it stay too long when it
should have been reverted, I think we should take more time to work on
this feature, revert it for PG17, and target it for PG18.
I understand it's disappointing to do a late revert of a feature, but I
think it's better to be safer, particularly if we believe there's a an
elevated risk of releasing something with vulnerabilities. As we saw
with SQL/JSON, this we'll give us more time to come up with design we
agree with, further test, and then promote as part of PG18.
Thanks,
Jonathan
Hi!
On Thu, Aug 22, 2024 at 7:33 PM Robert Haas <robertmhaas@gmail.com> wrote:
In response to some concerns raised about this fix on the
pgsql-release list today, I spent some time investigating this patch.
Unfortunately, I think there are too many problems here to be
reasonably fixed before release, and I think all of SPLIT/MERGE
PARTITION needs to be reverted.I focused my investigation on createPartitionTable(), which is a
helper for both SPLIT PARTITION and MERGE PARTITION, and it works by
consing up a CREATE TABLE AS statement and then feeding that back
through
ProcessUtility. I think it's bad design to use such a high-level
facility here; it is unlike what we do elsewhere in tablecmds.c and
opens us up to a variety of problems. The first thing that I
discovered is that this patch does not fix all of the repeated name
lookup problems. There is still this:tlc->relation =
makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
RelationGetRelationName(modelRel), -1);And also this:
createStmt->tablespacename =
get_tablespace_name(modelRel->rd_rel->reltablespace);In both cases, we do a reverse lookup on an OID to get a name which
the CREATE TABLE code will later turn back into an OID. If we don't
get the same value, that's at least a bug and probably a security
vulnerability, and there is no way to be certain that we will get the
same value. The only remedy is to not repeat the lookup in the first
place.Then I got to looking at this:
tlc->options = CREATE_TABLE_LIKE_ALL &
~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY |
CREATE_TABLE_LIKE_STATISTICS);It's not obvious at first glance that there is a critical problem
here, but there are reasons to be nervous. We're deploying a lot of
machinery here to copy a lot of stuff and, while that's efficient from
a coding perspective, it means that stuff you might not expect can
just kind of happen. For instance:robert.haas=# \d+
List of relations
Schema | Name | Type | Owner | Persistence |
Access method | Size | Description
--------+------+-------------------+-------------+-------------+---------------+------------+-------------
public | foo | partitioned table | robert.haas | permanent |
| 0 bytes |
public | foo1 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo2 | table | bob | permanent | heap
| 8192 bytes |
(3 rows)
robert.haas=# alter table foo split partition foo2 into (partition
foo3 for values from (10) to (15), partition foo4 for values from (15)
to (20));
ALTER TABLE
robert.haas=# \d+
List of relations
Schema | Name | Type | Owner | Persistence |
Access method | Size | Description
--------+------+-------------------+-------------+-------------+---------------+------------+-------------
public | foo | partitioned table | robert.haas | permanent |
| 0 bytes |
public | foo1 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo3 | table | robert.haas | permanent | heap
| 8192 bytes |
public | foo4 | table | robert.haas | permanent | heap
| 8192 bytes |
(4 rows)I've split a partition owned by bob into two partitions owned by
robert.haas. That's rather surprising. It doesn't work to split a
partition that I don't own (and thus gain access to it) but if the
superuser splits a non-superuser's partition, the superuser ends
upowning the new partitions. I don't know if that's a vulnerability or
just unexpected. However, then I found this, which I'm pretty well
certain is a vulnerability:robert.haas=# set role bob;
SET
robert.haas=> create table foo (a int, b text) partition by range (a);
CREATE TABLE
robert.haas=> create table foo1 partition of foo for values from (0) to (10);
CREATE TABLE
robert.haas=> create table foo2 partition of foo for values from (10) to (20);
CREATE TABLE
robert.haas=> insert into foo values (11, 'carrots'), (16, 'pineapple');
INSERT 0 2
robert.haas=> create or replace function run_me(integer) returns
integer as $$begin raise notice 'you are running me as %',
current_user; return $1; end$$ language plpgsql immutable;
CREATE FUNCTION
robert.haas=> create index on foo (run_me(a));
NOTICE: you are running me as bob
NOTICE: you are running me as bob
CREATE INDEX
robert.haas=> reset role;
RESET
robert.haas=# alter table foo split partition foo2 into (partition
foo3 for values from (10) to (15), partition foo4 for values from (15)
to (20));
NOTICE: you are running me as robert.haas
NOTICE: you are running me as robert.haas
ALTER TABLEI think it is very unlikely that the problems mentioned above are the
only ones. They're just what I found in an hour or two of testing.
Even if they were, we're probably too close to release to be rushing
out last minute fixes to multiple unanticipated security problems. But
because of the design that was chosen here, I think there is probably
more stuff here that is not right, some of which is security relevant
and some of which is just a question of whether we're really getting
the behavior that we want. And I don't think we can fix all that
without either a very large number of grotty hacks similar to the one
installed by 04158e7fa37c2dda9c3421ca922d02807b86df19, or a complete
redesign of the feature. I believe the latter is probably a wiser
course of action.
Thank you for your feedback. Yes, it seems that there is not enough
time to even carefully analyze all the issues in these features. The
rule of thumb I can get from this experience is "think multiple times
before accessing something already opened by its name". I'm going to
revert these features during next couple days.
------
Regards,
Alexander Korotkov
Supabase
On Thu, Aug 22, 2024 at 12:43 PM Alexander Korotkov
<aekorotkov@gmail.com> wrote:
Thank you for your feedback. Yes, it seems that there is not enough
time to even carefully analyze all the issues in these features. The
rule of thumb I can get from this experience is "think multiple times
before accessing something already opened by its name". I'm going to
revert these features during next couple days.
Thanks, and sorry about that. I would say even "think multiple times"
is possibly not strong enough -- it might almost be "just don't ever
do it". Even if (in some particular case) the invalidation mechanism
seems to protect you from getting wrong answers, there are often holes
in that, specifically around search_path = foo, bar and you're
operating on an object in schema bar and an identically-named object
is created in schema foo at just the wrong time. Sometimes there are
problems even when search_path is not involved, but when it is, there
are more.
Here, aside from the name lookup issues, there are also problems with
expression evaluation: we can't split partitions without reindexing
rows that those partitions contain, and it is critical to think
through which is going to do the evaluation and make sure it's
properly sandboxed. I think we might need
SECURITY_RESTRICTED_OPERATION here.
Another thing I want to highlight if you do have another go at this
patch is that it's really critical to think about where every single
property of the newly-created tables comes from. The original patch
didn't consider relpersistence or tableam, and here I just discovered
that owner is also an issue that probably needs more consideration,
but it goes way beyond that. For example, I was surprised to discover
that if I put per-partition constraints or triggers on a partition and
then split it, they were not duplicated to the new partitions. Now,
maybe that's actually the behavior we want -- I'm not 100% positive --
but it sure wasn't what I was expecting. If we did duplicate them when
splitting, then what's supposed to happen when merging occurs? That is
not at all obvious, at least to me, but it needs careful thought. ACLs
and rules and default values and foreign keys (both outbond and
inbound) all need to be considered too, along with 27 other things
that I'm sure I'm not thinking about right now. Some of this behavior
should probably be explicitly documented, but all of it should be
considered carefully enough before commit to avoid surprises later. I
say that both from a security point of view and also just from a user
experience point of view. Even if things aren't insecure, they can
still be annoying, but it's not uncommon in cases like this for
annoying things to turn out to also be insecure.
Finally, if you do revisit this, I believe it would be a good idea to
think a bit harder about how data is moved around. My impression (and
please correct me if I am mistaken) is that currently, any split or
merge operation rewrites all the data in the source partition(s). If a
large partition is being split nearly equally, I think that has a good
chance of being optimal, but I think that might be the only case. If
we're merging partitions, wouldn't it be better to adjust the
constraints on the first partition -- or perhaps the largest partition
if we want to be clever -- and insert the data from all of the others
into it? Maybe that would even have syntax that puts the user in
control of which partition survives, e.g. ALTER TABLE tab1 MERGE
PARTITION part1 WITH part2, part3, .... That would also make it really
obvious to the user what all of the properties of part1 will be after
the merge: they will be exactly the same as they were before the
merge, except that the partition constraint will have been adjusted.
You basically dodge everything in the previous paragraph in one shot,
and it seems like it would also be faster. Splitting there's no
similar get-out-of-jail free card, at least not that I can see. Even
if you add syntax that splits a partition by using INSERT/DELETE to
move some rows to a newly-created partition, you still have to make at
least one new partition. But possibly that syntax is worth having
anyway, because it would be a lot quicker in the case of a highly
asymmetric split. On the other hand, maybe even splits are much more
likely and we don't really need it. I don't know.
--
Robert Haas
EDB: http://www.enterprisedb.com
On Thu, Aug 22, 2024 at 8:25 PM Robert Haas <robertmhaas@gmail.com> wrote:
On Thu, Aug 22, 2024 at 12:43 PM Alexander Korotkov
<aekorotkov@gmail.com> wrote:Thank you for your feedback. Yes, it seems that there is not enough
time to even carefully analyze all the issues in these features. The
rule of thumb I can get from this experience is "think multiple times
before accessing something already opened by its name". I'm going to
revert these features during next couple days.Thanks, and sorry about that. I would say even "think multiple times"
is possibly not strong enough -- it might almost be "just don't ever
do it". Even if (in some particular case) the invalidation mechanism
seems to protect you from getting wrong answers, there are often holes
in that, specifically around search_path = foo, bar and you're
operating on an object in schema bar and an identically-named object
is created in schema foo at just the wrong time. Sometimes there are
problems even when search_path is not involved, but when it is, there
are more.Here, aside from the name lookup issues, there are also problems with
expression evaluation: we can't split partitions without reindexing
rows that those partitions contain, and it is critical to think
through which is going to do the evaluation and make sure it's
properly sandboxed. I think we might need
SECURITY_RESTRICTED_OPERATION here.Another thing I want to highlight if you do have another go at this
patch is that it's really critical to think about where every single
property of the newly-created tables comes from. The original patch
didn't consider relpersistence or tableam, and here I just discovered
that owner is also an issue that probably needs more consideration,
but it goes way beyond that. For example, I was surprised to discover
that if I put per-partition constraints or triggers on a partition and
then split it, they were not duplicated to the new partitions. Now,
maybe that's actually the behavior we want -- I'm not 100% positive --
but it sure wasn't what I was expecting. If we did duplicate them when
splitting, then what's supposed to happen when merging occurs? That is
not at all obvious, at least to me, but it needs careful thought. ACLs
and rules and default values and foreign keys (both outbond and
inbound) all need to be considered too, along with 27 other things
that I'm sure I'm not thinking about right now. Some of this behavior
should probably be explicitly documented, but all of it should be
considered carefully enough before commit to avoid surprises later. I
say that both from a security point of view and also just from a user
experience point of view. Even if things aren't insecure, they can
still be annoying, but it's not uncommon in cases like this for
annoying things to turn out to also be insecure.Finally, if you do revisit this, I believe it would be a good idea to
think a bit harder about how data is moved around. My impression (and
please correct me if I am mistaken) is that currently, any split or
merge operation rewrites all the data in the source partition(s). If a
large partition is being split nearly equally, I think that has a good
chance of being optimal, but I think that might be the only case. If
we're merging partitions, wouldn't it be better to adjust the
constraints on the first partition -- or perhaps the largest partition
if we want to be clever -- and insert the data from all of the others
into it? Maybe that would even have syntax that puts the user in
control of which partition survives, e.g. ALTER TABLE tab1 MERGE
PARTITION part1 WITH part2, part3, .... That would also make it really
obvious to the user what all of the properties of part1 will be after
the merge: they will be exactly the same as they were before the
merge, except that the partition constraint will have been adjusted.
You basically dodge everything in the previous paragraph in one shot,
and it seems like it would also be faster. Splitting there's no
similar get-out-of-jail free card, at least not that I can see. Even
if you add syntax that splits a partition by using INSERT/DELETE to
move some rows to a newly-created partition, you still have to make at
least one new partition. But possibly that syntax is worth having
anyway, because it would be a lot quicker in the case of a highly
asymmetric split. On the other hand, maybe even splits are much more
likely and we don't really need it. I don't know.
Thank you for so valuable feedback! When I have another go over this
patch I will ensure this is addressed.
------
Regards,
Alexander Korotkov
Supabase
Hi!
Alexander Korotkov, Robert Haas - thanks for fixes and feedbacks!
This email is a starting point for further work.
There are two files attached to this email:
v32-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch,
v32-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch.
They contains changes from reverted commits 1adf16b8fb, 87c21bb941, and
subsequent fixes and improvements including df64c81ca9, c99ef1811a,
9dfcac8e15, 885742b9f8, 842c9b2705, fcf80c5d5f, 96c7381c4c, f4fc7cb54b,
60ae37a8bc, 259c96fa8f, 449cdcd486, 3ca43dbbb6, 2a679ae94e, 3a82c689fd,
fbd4321fd5, d53a4286d7, c086896625, 4e5d6c4091.
I didn't include fix 04158e7fa3 into patches because Robert Haas
objected to its use.
A short list of known issues and questions (see more details in [1]/messages/by-id/CA+TgmobHYix=Nn8D4RUHa6fhUVPR88KGAMq1pBfnGfOfEjRixA@mail.gmail.com. and
[2]: /messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
1. Function createPartitionTable() should be rewritten using partitioned
table OID (not name) and without using ProcessUtility().
2. Should it be considered an error when we split a partition owned by
another user and get partitions that owned by our user?
(I think this is not a problem. Perhaps disallow merging other users'
partitions would be too strict a restriction.)
3. About the functional index "create index on foo (run_me(a));".
(Should we disallow merging of another user's partitions when
partitioned table has functional indexes? SECURITY_RESTRICTED_OPERATION?)
4. Need to decide what is correct in case there are per-partition
constraints or triggers on a split partition. They not duplicated to the
new partitions now. (But might be in this case we should have an error
or warning?)
5. "If we're merging partitions, wouldn't it be better to adjust the
constraints on the first partition - or perhaps the largest partition if
we want to be clever -- and insert the data from all of the others into
it? Maybe that would even have syntax that puts the user in control of
which partition survives, e.g. ALTER TABLE tab1 MERGE PARTITION part1
WITH part2, part3, .... That would also make it really obvious to the
user what all of the properties of part1 will be after the merge: they
will be exactly the same as they were before the merge, except that the
partition constraint will have been adjusted."
(Similar optimization was proposed in [3]/messages/by-id/c3730d78-6081-4c41-9715-d1d192734576@postgrespro.ru, see v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch but was rejected [4]/messages/by-id/CAPpHfdtj7YsPaASoVPN+N3H4_Ct+kQw8QY1d_9u7FPnbghkicw@mail.gmail.com).
Links.
[1]: /messages/by-id/CA+TgmobHYix=Nn8D4RUHa6fhUVPR88KGAMq1pBfnGfOfEjRixA@mail.gmail.com.
/messages/by-id/CA+TgmobHYix=Nn8D4RUHa6fhUVPR88KGAMq1pBfnGfOfEjRixA@mail.gmail.com.
[2]: /messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
/messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
[3]: /messages/by-id/c3730d78-6081-4c41-9715-d1d192734576@postgrespro.ru, see v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch
/messages/by-id/c3730d78-6081-4c41-9715-d1d192734576@postgrespro.ru,
see v31-0003-Additional-patch-for-ALTER-TABLE-.-MERGE-PARTITI.patch
[4]: /messages/by-id/CAPpHfdtj7YsPaASoVPN+N3H4_Ct+kQw8QY1d_9u7FPnbghkicw@mail.gmail.com
/messages/by-id/CAPpHfdtj7YsPaASoVPN+N3H4_Ct+kQw8QY1d_9u7FPnbghkicw@mail.gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v32-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v32-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From a934c8855cb1b05474a34a4417eb0ed1c00bc5db Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v32 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 90 +-
src/backend/commands/tablecmds.c | 420 +++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 131 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.c | 10 +
src/include/nodes/parsenodes.h | 14 +
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 | 945 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
18 files changed, 2715 insertions(+), 24 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index b671858627..2770e81656 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4353,6 +4353,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 1a49f321cf..b99d4972ac 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1117,14 +1120,87 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The new partition will be created the same as a table created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1367,7 +1443,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1783,6 +1860,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dac39df83a..4d24278495 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -657,6 +657,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4676,6 +4678,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessShareLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5093,6 +5099,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);
@@ -5489,6 +5500,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);
@@ -6477,6 +6496,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:
@@ -18285,6 +18306,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -18487,23 +18539,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20018,3 +20055,352 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
+ AlterTableUtilityContext *context)
+{
+ CreateStmt *createStmt;
+ TableLikeClause *tlc;
+ PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
+
+ createStmt = makeNode(CreateStmt);
+ createStmt->relation = newPartName;
+ createStmt->tableElts = NIL;
+ createStmt->inhRelations = NIL;
+ createStmt->constraints = NIL;
+ createStmt->options = NIL;
+ createStmt->oncommit = ONCOMMIT_NOOP;
+ createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
+ createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
+
+ tlc = makeNode(TableLikeClause);
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
+
+ /*
+ * Indexes will be inherited on "attach new partitions" stage, after data
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
+ */
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
+ 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);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 84cef57a70..d85c74cb7c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -760,7 +760,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2318,6 +2318,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2332,6 +2333,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2345,6 +2347,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2361,6 +2378,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17691,6 +17709,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18314,6 +18333,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 79cad4ab30..63ea2ec5ea 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3229,6 +3232,121 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3505,6 +3623,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 contain 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 c28639d2e3..6cb32d57ef 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index a7ccde6d7d..c3ea87fcb9 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2620,6 +2621,15 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 124d853e49..b6e7957ebb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -937,6 +937,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -945,6 +956,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2400,6 +2413,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 f8659078ce..6b256fcece 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -335,6 +335,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 2758ae82d7..cc341afdf4 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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..59836e2d35
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,945 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f53a526f7c..0014801684 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9e951a9e6f..ddc4c78fb9 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2659,6 +2659,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v32-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v32-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 71a05398ce52c634cdf3a1cee45ada938118d125 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v32 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 79 +-
src/backend/commands/tablecmds.c | 398 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 64 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1589 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 962 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4109 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 2770e81656..5f481dda3a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4374,6 +4374,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index b99d4972ac..6a2822adad 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1120,6 +1124,58 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The new partitions will be created the same as tables created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1200,7 +1256,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1444,7 +1501,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1860,6 +1917,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4d24278495..55db12ef35 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -657,6 +657,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4678,6 +4681,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessShareLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5099,6 +5106,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5500,6 +5512,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6496,6 +6516,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20056,6 +20078,256 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -20160,6 +20432,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d85c74cb7c..c3f25582c3 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -269,6 +269,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -775,7 +778,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2308,6 +2311,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17777,6 +17811,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18413,6 +18448,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 63ea2ec5ea..d5c2b2ff0b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3270,6 +3270,45 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3615,7 +3654,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3623,6 +3662,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3631,7 +3671,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4026,13 +4070,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4041,9 +4085,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4051,7 +4095,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6cb32d57ef..4eda59767c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 00eda1b34c..4039ee0df7 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13296,3 +13296,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index c3ea87fcb9..0d25981253 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,7 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2610,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2621,6 +2621,10 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b6e7957ebb..85a62b538e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2413,6 +2413,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 6b256fcece..bb191b1f46 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -418,6 +418,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 cc341afdf4..67ff2b6367 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..dc9a5130cc
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1589 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 0014801684..2429ec2bba 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ef5ea07f74
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,962 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ddc4c78fb9..16dcd62335 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2723,6 +2723,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Tue, Aug 27, 2024 at 2:24 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
They contains changes from reverted commits 1adf16b8fb, 87c21bb941, and
subsequent fixes and improvements including df64c81ca9, c99ef1811a,
9dfcac8e15, 885742b9f8, 842c9b2705, fcf80c5d5f, 96c7381c4c, f4fc7cb54b,
60ae37a8bc, 259c96fa8f, 449cdcd486, 3ca43dbbb6, 2a679ae94e, 3a82c689fd,
fbd4321fd5, d53a4286d7, c086896625, 4e5d6c4091.
I didn't include fix 04158e7fa3 into patches because Robert Haas
objected to its use.
To be clear, I'm not against 04158e7fa3. I just don't think it fixes everything.
1. Function createPartitionTable() should be rewritten using partitioned
table OID (not name) and without using ProcessUtility().
Agree.
2. Should it be considered an error when we split a partition owned by
another user and get partitions that owned by our user?
(I think this is not a problem. Perhaps disallow merging other users'
partitions would be too strict a restriction.)3. About the functional index "create index on foo (run_me(a));".
(Should we disallow merging of another user's partitions when
partitioned table has functional indexes? SECURITY_RESTRICTED_OPERATION?)4. Need to decide what is correct in case there are per-partition
constraints or triggers on a split partition. They not duplicated to the
new partitions now. (But might be in this case we should have an error
or warning?)
I think we want to avoid giving errors or warnings. For all of these
cases, and others, we need to consider what the expected behavior is,
and have test cases and documentation as appropriate. But we shouldn't
think of it as "let's make it fail if the user does something that's
not safe" but rather "let's figure out how to make it safe."
5. "If we're merging partitions, wouldn't it be better to adjust the
constraints on the first partition - or perhaps the largest partition if
we want to be clever -- and insert the data from all of the others into
it? Maybe that would even have syntax that puts the user in control of
which partition survives, e.g. ALTER TABLE tab1 MERGE PARTITION part1
WITH part2, part3, .... That would also make it really obvious to the
user what all of the properties of part1 will be after the merge: they
will be exactly the same as they were before the merge, except that the
partition constraint will have been adjusted."
(Similar optimization was proposed in [3] but was rejected [4]).
Interesting. Maybe it would be a good idea to set up some test cases
to see which approach is better in different cases. Like try moving
data from foo1 to foo2 with DELETE..INSERT vs. creating a new table
with CTAS from foo1 UNION ALL foo2 and then indexing it. I think
Alexander has a good point there, but I think my point is good too so
I'm not sure which way wins.
--
Robert Haas
EDB: http://www.enterprisedb.com
Hi!
I plan to prepare fixes for issues from email [1]/messages/by-id/859476bf-3cb0-455e-b093-b8ab5ef17f0e@postgrespro.ru as separate commits
(for better code readability). Attachment in this email is a variant of
fix for the issue:
1. Function createPartitionTable() should be rewritten using
partitioned table OID (not name) and without using ProcessUtility().
Patch "Refactor createPartitionTable to remove ProcessUtility call"
contains code changes + test (see file
v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch).
But I'm not sure that refactoring createPartitionTable is the best
solution. PostgreSQL code has issue CVE-2014-0062 (commit 5f17304) - see
relation_openrv() call in expandTableLikeClause() function [2]https://github.com/postgres/postgres/blob/c39afc38cfec7c34b883095062a89a63b221521a/src/backend/parser/parse_utilcmd.c#L1171 (opening
relation by name after we got relation Oid).
Example for reproduce relation_openrv() call:
CREATE TABLE t (b bigint, i int DEFAULT 100);
CREATE TABLE t1 (LIKE t_bigint INCLUDING ALL);
Commit 04158e7fa3 [3]https://github.com/postgres/postgres/commit/04158e7fa37c2dda9c3421ca922d02807b86df19 (by Alexander Korotkov) might be a good fix for
this issue. But if we keep commit 04158e7fa3, do we need to refactor the
createPartitionTable function (for removing ProcessUtility)?
Perhaps the existing code
1) v33-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch
2) v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch +
with patch 04158e7fa3 will look better.
I would be very grateful for comments and suggestions.
Links.
[1]: /messages/by-id/859476bf-3cb0-455e-b093-b8ab5ef17f0e@postgrespro.ru
/messages/by-id/859476bf-3cb0-455e-b093-b8ab5ef17f0e@postgrespro.ru
[2]: https://github.com/postgres/postgres/blob/c39afc38cfec7c34b883095062a89a63b221521a/src/backend/parser/parse_utilcmd.c#L1171
https://github.com/postgres/postgres/blob/c39afc38cfec7c34b883095062a89a63b221521a/src/backend/parser/parse_utilcmd.c#L1171
[3]: https://github.com/postgres/postgres/commit/04158e7fa37c2dda9c3421ca922d02807b86df19
https://github.com/postgres/postgres/commit/04158e7fa37c2dda9c3421ca922d02807b86df19
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v33-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v33-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From dd414c86b18492ae97cf55164244af3bcdc00384 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v33 1/3] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 90 +-
src/backend/commands/tablecmds.c | 420 +++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 131 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.c | 10 +
src/include/nodes/parsenodes.h | 14 +
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 | 945 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
18 files changed, 2715 insertions(+), 24 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index b671858627..2770e81656 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4353,6 +4353,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 1a49f321cf..b99d4972ac 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1117,14 +1120,87 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The new partition will be created the same as a table created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_name</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1367,7 +1443,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1783,6 +1860,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b3cc6f8f69..1b845a6614 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -658,6 +658,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4677,6 +4679,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessShareLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5074,6 +5080,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);
@@ -5470,6 +5481,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);
@@ -6458,6 +6477,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:
@@ -18280,6 +18301,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -18482,23 +18534,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20013,3 +20050,352 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Emulates command: CREATE [TEMP] TABLE <newPartName> (LIKE <modelRel's name>
+ * INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
+ AlterTableUtilityContext *context)
+{
+ CreateStmt *createStmt;
+ TableLikeClause *tlc;
+ PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
+
+ createStmt = makeNode(CreateStmt);
+ createStmt->relation = newPartName;
+ createStmt->tableElts = NIL;
+ createStmt->inhRelations = NIL;
+ createStmt->constraints = NIL;
+ createStmt->options = NIL;
+ createStmt->oncommit = ONCOMMIT_NOOP;
+ createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
+ createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
+
+ tlc = makeNode(TableLikeClause);
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
+
+ /*
+ * Indexes will be inherited on "attach new partitions" stage, after data
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
+ */
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
+ 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);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 84cef57a70..d85c74cb7c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -760,7 +760,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2318,6 +2318,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2332,6 +2333,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2345,6 +2347,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2361,6 +2378,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17691,6 +17709,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18314,6 +18333,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 79cad4ab30..63ea2ec5ea 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3229,6 +3232,121 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3505,6 +3623,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 contain 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 c28639d2e3..6cb32d57ef 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index a7ccde6d7d..c3ea87fcb9 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,6 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2620,6 +2621,15 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 124d853e49..b6e7957ebb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -937,6 +937,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -945,6 +956,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2400,6 +2413,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 f8659078ce..6b256fcece 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -335,6 +335,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 2758ae82d7..cc341afdf4 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,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..59836e2d35
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,945 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 7a5a910562..79c9a023fd 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9e951a9e6f..ddc4c78fb9 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2659,6 +2659,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v33-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v33-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 14135f0a073bf0e04ee8bf35c757735a10fb2d8a Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v33 2/3] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 79 +-
src/backend/commands/tablecmds.c | 398 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 64 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1589 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 962 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4109 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 2770e81656..626d35514c 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4374,6 +4374,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index b99d4972ac..6a2822adad 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1120,6 +1124,58 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The new partitions will be created the same as tables created with the
+ SQL command <literal>CREATE TABLE <replaceable class="parameter">partition_nameN</replaceable> (LIKE <replaceable class="parameter">name</replaceable> INCLUDING ALL EXCLUDING INDEXES EXCLUDING IDENTITY EXCLUDING STATISTICS)</literal>.
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1200,7 +1256,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of ALTER TABLE that act on a single table, except
<literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1444,7 +1501,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1860,6 +1917,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1b845a6614..84eda40eb3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -658,6 +658,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4679,6 +4682,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessShareLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5080,6 +5087,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_TABLE);
/* No command-specific prep needed */
@@ -5481,6 +5493,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6477,6 +6497,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20051,6 +20073,256 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -20155,6 +20427,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d85c74cb7c..c3f25582c3 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -269,6 +269,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -645,6 +646,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -775,7 +778,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2308,6 +2311,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2352,6 +2372,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17777,6 +17811,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18413,6 +18448,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 63ea2ec5ea..d5c2b2ff0b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -136,7 +136,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3270,6 +3270,45 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent))));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3615,7 +3654,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3623,6 +3662,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3631,7 +3671,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4026,13 +4070,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4041,9 +4085,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4051,7 +4095,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6cb32d57ef..4eda59767c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b31be31321..f4ac473ca8 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13348,3 +13348,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index c3ea87fcb9..0d25981253 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -2353,7 +2353,7 @@ psql_completion(const char *text, int start, int end)
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2610,10 +2610,10 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2621,6 +2621,10 @@ psql_completion(const char *text, int start, int end)
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b6e7957ebb..85a62b538e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2413,6 +2413,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 6b256fcece..bb191b1f46 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -418,6 +418,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 cc341afdf4..67ff2b6367 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -300,6 +300,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..dc9a5130cc
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1589 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 79c9a023fd..b0804691f5 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ef5ea07f74
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,962 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ddc4c78fb9..16dcd62335 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2723,6 +2723,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchtext/plain; charset=UTF-8; name=v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchDownload
From 40820a0ee599c48643208ab5f49831f4a2415053 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 29 Aug 2024 20:27:03 +0300
Subject: [PATCH v33 3/3] Refactor createPartitionTable to remove
ProcessUtility call
---
src/backend/catalog/heap.c | 8 +-
src/backend/commands/tablecmds.c | 278 ++++++++++++++----
src/include/catalog/heap.h | 6 +
src/test/regress/expected/partition_split.out | 59 ++++
src/test/regress/sql/partition_split.sql | 21 ++
5 files changed, 314 insertions(+), 58 deletions(-)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 01b43cc6a8..7071343043 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -101,16 +101,12 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
-static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
- bool is_validated, bool is_local, int inhcount,
- bool is_no_inherit, bool is_internal);
static void StoreConstraints(Relation rel, List *cooked_constraints,
bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_initially_valid,
bool is_no_inherit);
-static void SetRelationNumChecks(Relation rel, int numchecks);
static Node *cookConstraint(ParseState *pstate,
Node *raw_constraint,
char *relname);
@@ -2070,7 +2066,7 @@ SetAttrMissing(Oid relid, char *attname, char *value)
*
* The OID of the new constraint is returned.
*/
-static Oid
+Oid
StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_validated, bool is_local, int inhcount,
bool is_no_inherit, bool is_internal)
@@ -2657,7 +2653,7 @@ MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
* relcache entries for the rel. Also, this backend will rebuild its
* own relcache entry at the next CommandCounterIncrement.
*/
-static void
+void
SetRelationNumChecks(Relation rel, int numchecks)
{
Relation relrel;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 84eda40eb3..e2a42a228e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -20323,6 +20323,179 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
}
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ (void) StoreAttrDefault(newRel, num, def, true, false);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ /* We can skip validation, since the new table should be empty. */
+ (void) StoreRelCheck(newRel, ccname, ccbin_node, true, true,
+ 0, ccnoinherit, false);
+ }
+
+ /* Update the count of constraints in the relation's pg_class tuple. */
+ SetRelationNumChecks(newRel, constr->num_check);
+}
+
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -20337,13 +20510,14 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
-createPartitionTable(RangeVar *newPartName, Relation modelRel,
- AlterTableUtilityContext *context)
+createPartitionTable(RangeVar *newPartName, Relation modelRel)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
/* If existing rel is temp, it must belong to this session */
if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
@@ -20352,56 +20526,53 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create as partition of temporary relation of another session")));
- /* New partition should have the same persistence as modelRel */
- newPartName->relpersistence = modelRel->rd_rel->relpersistence;
-
- createStmt = makeNode(CreateStmt);
- createStmt->relation = newPartName;
- createStmt->tableElts = NIL;
- createStmt->inhRelations = NIL;
- createStmt->constraints = NIL;
- createStmt->options = NIL;
- createStmt->oncommit = ONCOMMIT_NOOP;
- createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
- createStmt->if_not_exists = false;
- createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
-
- tlc = makeNode(TableLikeClause);
- tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
- RelationGetRelationName(modelRel), -1);
-
- /*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving. We also don't copy the extended statistics for consistency
- * with CREATE TABLE PARTITION OF.
- */
- tlc->options = CREATE_TABLE_LIKE_ALL &
- ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
- 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);
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ GetUserId(),
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
/*
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(newRelId, NoLock);
/*
* We intended to create the partition with the same persistence as the
@@ -20424,6 +20595,9 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
RelationGetRelationName(modelRel))));
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
return newRel;
}
@@ -20521,7 +20695,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRel = createPartitionTable(sps->name, rel);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -20765,7 +20939,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create table for new partition, use partitioned table as model. */
- newPartRel = createPartitionTable(cmd->name, rel, context);
+ newPartRel = createPartitionTable(cmd->name, rel);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index c512824cd1..9fd52a4f39 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -114,6 +114,12 @@ extern List *AddRelationNewConstraints(Relation rel,
bool is_internal,
const char *queryString);
+extern Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
+ bool is_validated, bool is_local, int inhcount,
+ bool is_no_inherit, bool is_internal);
+
+extern void SetRelationNumChecks(Relation rel, int numchecks);
+
extern void RelationClearMissing(Relation rel);
extern void SetAttrMissing(Oid relid, char *attname, char *value);
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index dc9a5130cc..205ddb0f77 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1583,6 +1583,65 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
(PARTITION tp_0 FOR VALUES FROM (0) TO (1),
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
RESET search_path;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index ef5ea07f74..e185458e4e 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -955,6 +955,27 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
RESET search_path;
--
--
2.40.1.windows.1
Hi!
On Fri, Aug 30, 2024 at 11:43 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
I plan to prepare fixes for issues from email [1] as separate commits
(for better code readability). Attachment in this email is a variant of
fix for the issue:1. Function createPartitionTable() should be rewritten using
partitioned table OID (not name) and without using ProcessUtility().Patch "Refactor createPartitionTable to remove ProcessUtility call"
contains code changes + test (see file
v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch).But I'm not sure that refactoring createPartitionTable is the best
solution. PostgreSQL code has issue CVE-2014-0062 (commit 5f17304) - see
relation_openrv() call in expandTableLikeClause() function [2] (opening
relation by name after we got relation Oid).
Example for reproduce relation_openrv() call:CREATE TABLE t (b bigint, i int DEFAULT 100);
CREATE TABLE t1 (LIKE t_bigint INCLUDING ALL);Commit 04158e7fa3 [3] (by Alexander Korotkov) might be a good fix for
this issue. But if we keep commit 04158e7fa3, do we need to refactor the
createPartitionTable function (for removing ProcessUtility)?
Perhaps the existing code
1) v33-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch
2) v33-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch +
with patch 04158e7fa3 will look better.I would be very grateful for comments and suggestions.
Thank you for continuing your work on the subject. The patches
currently doesn't apply cleanly. Please, rebase.
I think getting away from expandTableLikeClause() is the right
direction to resolve the security problems. That looks great, it
finally not as complex as I thought. I think the code requires some
polishing: you need to revise the comments given its not part of LIKE
clause handling anymore.
I see fixes for the issues mentioned in [1] and [2] are still not
implemented. Do you plan to do this in this release cycle?
Links.
1. /messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
2. /messages/by-id/859476bf-3cb0-455e-b093-b8ab5ef17f0e@postgrespro.ru
------
Regards,
Alexander Korotkov
Supabase
Thank you for email!
The patches currently doesn't apply cleanly. Please, rebase.
I did rebase and made few fixes that were needed after the recent
vanilla changes (added ATT_PARTITIONED_TABLE flag for
ATSimplePermissions function + added creation of not-null constraints in
the createTableConstraints function).
The patches are attached to the email.
I think the code requires some polishing: you need to revise
the comments given its not part of LIKE clause handling anymore.
I removed couple of lines from comment and a few lines from
documentation, I hope that's enough ...
I see fixes for the issues mentioned in [1] and [2] are still not
implemented. Do you plan to do this in this release cycle?
I would like to make some changes, but I think it would be appropriate
to discuss these points first.
As far as I understand, there is currently no clear opinion on how to
implement [1] and [2].
I would appreciate your opinions on what improvements are really needed
and in what order they should be implemented.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v34-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v34-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From f088f654411516e2d924c07c61296944fc89cdc2 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v34 1/3] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 88 +-
src/backend/commands/tablecmds.c | 417 +++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/nodes/parsenodes.h | 14 +
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 | 947 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
18 files changed, 2707 insertions(+), 24 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index dea04d64db..e6ad4144f8 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4417,6 +4417,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index c8f7ab7d95..690e8e99c5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1119,14 +1122,85 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1369,7 +1443,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1785,6 +1860,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 6ccae4cb4a..34f7aa6130 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -689,6 +689,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4757,6 +4759,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5190,6 +5196,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5584,6 +5595,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);
@@ -6563,6 +6582,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:
@@ -18980,6 +19001,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19183,23 +19235,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -20808,3 +20845,349 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
+ AlterTableUtilityContext *context)
+{
+ CreateStmt *createStmt;
+ TableLikeClause *tlc;
+ PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
+
+ createStmt = makeNode(CreateStmt);
+ createStmt->relation = newPartName;
+ createStmt->tableElts = NIL;
+ createStmt->inhRelations = NIL;
+ createStmt->constraints = NIL;
+ createStmt->options = NIL;
+ createStmt->oncommit = ONCOMMIT_NOOP;
+ createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
+ createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
+
+ tlc = makeNode(TableLikeClause);
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
+
+ /*
+ * Indexes will be inherited on "attach new partitions" stage, after data
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
+ */
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
+ 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);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 67eb96396a..713aac246e 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -748,7 +748,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2324,6 +2324,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2338,6 +2339,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2351,6 +2353,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2367,6 +2384,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17802,6 +17820,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18426,6 +18445,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 0f324ee4e3..4c670765a6 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3476,6 +3479,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3753,6 +3866,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 contain 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 c28639d2e3..6cb32d57ef 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index bbd08770c3..8f52056fe8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,6 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2951,6 +2952,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e..470082e12a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -939,6 +939,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -947,6 +958,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2419,6 +2432,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 899d64ad55..1580d863f2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -335,6 +335,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 3d9cc1031f..0329d7bd84 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 98d237ac68..70f45b3c60 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..7a960fed8f
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,947 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 81e4222d26..ff55527ec6 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ce33e55bf1..6e55061044 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2666,6 +2666,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v34-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v34-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 2519a010e9ebd4dd5f9aed57a8dab6c606ee70c0 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v34 2/3] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 398 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1590 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 962 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4103 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index e6ad4144f8..a6a91293f7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4438,6 +4438,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 690e8e99c5..dd31e92bfb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1122,6 +1126,56 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1200,7 +1254,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1444,7 +1499,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1860,6 +1915,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 34f7aa6130..93d46d85b8 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -689,6 +689,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4759,6 +4762,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5196,6 +5203,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5595,6 +5607,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6582,6 +6602,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -20846,6 +20868,256 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -20947,6 +21219,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 713aac246e..52ca864b7a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -256,6 +256,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -633,6 +634,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -763,7 +766,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2314,6 +2317,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2358,6 +2378,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17889,6 +17923,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18526,6 +18561,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 4c670765a6..bf5feee4c1 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3517,6 +3517,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3858,7 +3892,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3866,6 +3900,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3874,7 +3909,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4269,13 +4308,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4284,9 +4323,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4294,7 +4333,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 6cb32d57ef..4eda59767c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2194ab3dfa..f9db87be4f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13546,3 +13546,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8f52056fe8..250a983f41 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,7 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2941,10 +2941,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2952,6 +2952,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 470082e12a..58972b22c6 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2432,6 +2432,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 1580d863f2..a4b4b330ce 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -419,6 +419,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 0329d7bd84..9d2a26705f 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 161fb5ef02..6d86080622 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 70f45b3c60..49cd292a0c 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..0128f53d93
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1590 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index ff55527ec6..24ab52afce 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ef5ea07f74
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,962 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6e55061044..f662ed0c41 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2730,6 +2730,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v34-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchtext/plain; charset=UTF-8; name=v34-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchDownload
From c5d88bf6ec53ea562736c62b71ab598159f6384a Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 29 Aug 2024 20:27:03 +0300
Subject: [PATCH v34 3/3] Refactor createPartitionTable to remove
ProcessUtility call
---
src/backend/catalog/heap.c | 8 +-
src/backend/commands/tablecmds.c | 290 ++++++++++++++----
src/include/catalog/heap.h | 6 +
src/test/regress/expected/partition_split.out | 59 ++++
src/test/regress/sql/partition_split.sql | 21 ++
5 files changed, 326 insertions(+), 58 deletions(-)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index d7b88b61dc..5e8078baf2 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -101,16 +101,12 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
-static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
- bool is_validated, bool is_local, int16 inhcount,
- bool is_no_inherit, bool is_internal);
static void StoreConstraints(Relation rel, List *cooked_constraints,
bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_initially_valid,
bool is_no_inherit);
-static void SetRelationNumChecks(Relation rel, int numchecks);
static Node *cookConstraint(ParseState *pstate,
Node *raw_constraint,
char *relname);
@@ -2072,7 +2068,7 @@ SetAttrMissing(Oid relid, char *attname, char *value)
*
* The OID of the new constraint is returned.
*/
-static Oid
+Oid
StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_validated, bool is_local, int16 inhcount,
bool is_no_inherit, bool is_internal)
@@ -3045,7 +3041,7 @@ AddRelationNotNullConstraints(Relation rel, List *constraints,
* relcache entries for the rel. Also, this backend will rebuild its
* own relcache entry at the next CommandCounterIncrement.
*/
-static void
+void
SetRelationNumChecks(Relation rel, int numchecks)
{
Relation relrel;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 93d46d85b8..2545320426 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21118,6 +21118,191 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
}
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ (void) StoreAttrDefault(newRel, num, def, true, false);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ /* We can skip validation, since the new table should be empty. */
+ (void) StoreRelCheck(newRel, ccname, ccbin_node, true, true,
+ 0, ccnoinherit, false);
+ }
+
+ /* Update the count of constraints in the relation's pg_class tuple. */
+ SetRelationNumChecks(newRel, constr->num_check);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -21129,13 +21314,14 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
-createPartitionTable(RangeVar *newPartName, Relation modelRel,
- AlterTableUtilityContext *context)
+createPartitionTable(RangeVar *newPartName, Relation modelRel)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
/* If existing rel is temp, it must belong to this session */
if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
@@ -21144,56 +21330,53 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create as partition of temporary relation of another session")));
- /* New partition should have the same persistence as modelRel */
- newPartName->relpersistence = modelRel->rd_rel->relpersistence;
-
- createStmt = makeNode(CreateStmt);
- createStmt->relation = newPartName;
- createStmt->tableElts = NIL;
- createStmt->inhRelations = NIL;
- createStmt->constraints = NIL;
- createStmt->options = NIL;
- createStmt->oncommit = ONCOMMIT_NOOP;
- createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
- createStmt->if_not_exists = false;
- createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
-
- tlc = makeNode(TableLikeClause);
- tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
- RelationGetRelationName(modelRel), -1);
-
- /*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving. We also don't copy the extended statistics for consistency
- * with CREATE TABLE PARTITION OF.
- */
- tlc->options = CREATE_TABLE_LIKE_ALL &
- ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
- 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);
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ GetUserId(),
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
/*
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(newRelId, NoLock);
/*
* We intended to create the partition with the same persistence as the
@@ -21216,6 +21399,9 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
RelationGetRelationName(modelRel))));
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
return newRel;
}
@@ -21313,7 +21499,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRel = createPartitionTable(sps->name, rel);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21557,7 +21743,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create table for new partition, use partitioned table as model. */
- newPartRel = createPartitionTable(cmd->name, rel, context);
+ newPartRel = createPartitionTable(cmd->name, rel);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index 8c278f202b..afa5e8628a 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -118,6 +118,12 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
+ bool is_validated, bool is_local, int16 inhcount,
+ bool is_no_inherit, bool is_internal);
+
+extern void SetRelationNumChecks(Relation rel, int numchecks);
+
extern void RelationClearMissing(Relation rel);
extern void SetAttrMissing(Oid relid, char *attname, char *value);
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 0128f53d93..a47a635e50 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1584,6 +1584,65 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
(PARTITION tp_0 FOR VALUES FROM (0) TO (1),
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
RESET search_path;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index ef5ea07f74..e185458e4e 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -955,6 +955,27 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
RESET search_path;
--
--
2.40.1.windows.1
Only patches v34-0001 and 2 has been tested.
Patch v34-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch do not apply anymore on src/backend/catalog/heap.c
The new status of this patch is: Waiting on Author
Only patches v34-0001 and 2 has been tested.
Patch v34-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch
do not apply anymore on src/backend/catalog/heap.c
Thanks, rebased.
The patches are attached to the email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v35-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v35-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 14ebf8cb9ea7688e8401637e7349d14bdf6942d6 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v35 1/3] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 88 +-
src/backend/commands/tablecmds.c | 417 +++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/nodes/parsenodes.h | 14 +
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 | 947 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
18 files changed, 2707 insertions(+), 24 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index dea04d64db..e6ad4144f8 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4417,6 +4417,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index f9576da435..a2e4e37034 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1121,85 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1442,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1786,6 +1861,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d617c4bc63..922dd53d09 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -701,6 +701,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4789,6 +4791,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5222,6 +5228,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5616,6 +5627,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);
@@ -6600,6 +6619,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:
@@ -19199,6 +19220,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19402,23 +19454,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -21050,3 +21087,349 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel,
+ AlterTableUtilityContext *context)
+{
+ CreateStmt *createStmt;
+ TableLikeClause *tlc;
+ PlannedStmt *wrapper;
+ Relation newRel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* New partition should have the same persistence as modelRel */
+ newPartName->relpersistence = modelRel->rd_rel->relpersistence;
+
+ createStmt = makeNode(CreateStmt);
+ createStmt->relation = newPartName;
+ createStmt->tableElts = NIL;
+ createStmt->inhRelations = NIL;
+ createStmt->constraints = NIL;
+ createStmt->options = NIL;
+ createStmt->oncommit = ONCOMMIT_NOOP;
+ createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
+ createStmt->if_not_exists = false;
+ createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
+
+ tlc = makeNode(TableLikeClause);
+ tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
+ RelationGetRelationName(modelRel), -1);
+
+ /*
+ * Indexes will be inherited on "attach new partitions" stage, after data
+ * moving. We also don't copy the extended statistics for consistency
+ * with CREATE TABLE PARTITION OF.
+ */
+ tlc->options = CREATE_TABLE_LIKE_ALL &
+ ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
+ 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);
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_openrv(newPartName, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel, context);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d7f9c00c40..f2787452e6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17871,6 +17889,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18496,6 +18515,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..5754a97683 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3485,6 +3488,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3762,6 +3875,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 81cbf10aa2..5c1393232a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,6 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2951,6 +2952,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ffe155ee20..36e53ef300 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -948,6 +948,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -956,6 +967,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2463,6 +2476,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 cf2917ad07..a0b21ced88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -336,6 +336,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..7a960fed8f
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,947 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1edd9e45eb..71a5d73143 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a2644a2e65..7bbcf20ef3 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2682,6 +2682,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v35-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v35-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 82e4e90f322ca811eee935beef7c426bf78ef921 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v35 2/3] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 398 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1590 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 962 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4103 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index e6ad4144f8..a6a91293f7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4438,6 +4438,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index a2e4e37034..98ce143dbb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1121,6 +1125,56 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1199,7 +1253,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1443,7 +1498,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1861,6 +1916,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 922dd53d09..3b7cab0d42 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -701,6 +701,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4791,6 +4794,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5228,6 +5235,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5627,6 +5639,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6619,6 +6639,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -21088,6 +21110,256 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -21189,6 +21461,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f2787452e6..d43e3f2791 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17958,6 +17992,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18596,6 +18631,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 5754a97683..9f86c4f056 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3867,7 +3901,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3875,6 +3909,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3883,7 +3918,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4316,13 +4355,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4331,9 +4370,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4341,7 +4380,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..9a3a281c84 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 54dad97555..249fa70234 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13618,3 +13618,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 5c1393232a..9d37fc9317 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,7 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2941,10 +2941,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2952,6 +2952,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 36e53ef300..3a88287b5d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2476,6 +2476,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a0b21ced88..1c03c74f1c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -420,6 +420,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index aa7a8a3800..52bd8aa51e 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..0128f53d93
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1590 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 71a5d73143..9bf7c37202 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ef5ea07f74
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,962 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 7bbcf20ef3..60c9383d0a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2746,6 +2746,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
v35-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchtext/plain; charset=UTF-8; name=v35-0003-Refactor-createPartitionTable-to-remove-ProcessU.patchDownload
From 856e6e71ac212ce9bf053ce47d4558a41e2d7953 Mon Sep 17 00:00:00 2001
From: Koval Dmitry <d.koval@postgrespro.ru>
Date: Thu, 29 Aug 2024 20:27:03 +0300
Subject: [PATCH v35 3/3] Refactor createPartitionTable to remove
ProcessUtility call
---
src/backend/catalog/heap.c | 8 +-
src/backend/commands/tablecmds.c | 291 ++++++++++++++----
src/include/catalog/heap.h | 6 +
src/test/regress/expected/partition_split.out | 59 ++++
src/test/regress/sql/partition_split.sql | 21 ++
5 files changed, 327 insertions(+), 58 deletions(-)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 57ef466acc..1476d0ec04 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -101,9 +101,6 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
-static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
- bool is_enforced, bool is_validated, bool is_local,
- int16 inhcount, bool is_no_inherit, bool is_internal);
static void StoreConstraints(Relation rel, List *cooked_constraints,
bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
@@ -111,7 +108,6 @@ static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *
bool is_enforced,
bool is_initially_valid,
bool is_no_inherit);
-static void SetRelationNumChecks(Relation rel, int numchecks);
static Node *cookConstraint(ParseState *pstate,
Node *raw_constraint,
char *relname);
@@ -2065,7 +2061,7 @@ SetAttrMissing(Oid relid, char *attname, char *value)
*
* The OID of the new constraint is returned.
*/
-static Oid
+Oid
StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal)
@@ -3065,7 +3061,7 @@ AddRelationNotNullConstraints(Relation rel, List *constraints,
* relcache entries for the rel. Also, this backend will rebuild its
* own relcache entry at the next CommandCounterIncrement.
*/
-static void
+void
SetRelationNumChecks(Relation rel, int numchecks)
{
Relation relrel;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3b7cab0d42..3dcb8595e5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -21360,6 +21360,192 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
}
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ (void) StoreAttrDefault(newRel, num, def, true, false);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ /* We can skip validation, since the new table should be empty. */
+ (void) StoreRelCheck(newRel, ccname, ccbin_node, ccenforced, true,
+ true, 0, ccnoinherit, false);
+ }
+
+ /* Update the count of constraints in the relation's pg_class tuple. */
+ SetRelationNumChecks(newRel, constr->num_check);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
/*
* createPartitionTable: create table for a new partition with given name
* (newPartName) like table (modelRel)
@@ -21371,13 +21557,14 @@ moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPar
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
-createPartitionTable(RangeVar *newPartName, Relation modelRel,
- AlterTableUtilityContext *context)
+createPartitionTable(RangeVar *newPartName, Relation modelRel)
{
- CreateStmt *createStmt;
- TableLikeClause *tlc;
- PlannedStmt *wrapper;
Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
/* If existing rel is temp, it must belong to this session */
if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
@@ -21386,56 +21573,53 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create as partition of temporary relation of another session")));
- /* New partition should have the same persistence as modelRel */
- newPartName->relpersistence = modelRel->rd_rel->relpersistence;
-
- createStmt = makeNode(CreateStmt);
- createStmt->relation = newPartName;
- createStmt->tableElts = NIL;
- createStmt->inhRelations = NIL;
- createStmt->constraints = NIL;
- createStmt->options = NIL;
- createStmt->oncommit = ONCOMMIT_NOOP;
- createStmt->tablespacename = get_tablespace_name(modelRel->rd_rel->reltablespace);
- createStmt->if_not_exists = false;
- createStmt->accessMethod = get_am_name(modelRel->rd_rel->relam);
-
- tlc = makeNode(TableLikeClause);
- tlc->relation = makeRangeVar(get_namespace_name(RelationGetNamespace(modelRel)),
- RelationGetRelationName(modelRel), -1);
-
- /*
- * Indexes will be inherited on "attach new partitions" stage, after data
- * moving. We also don't copy the extended statistics for consistency
- * with CREATE TABLE PARTITION OF.
- */
- tlc->options = CREATE_TABLE_LIKE_ALL &
- ~(CREATE_TABLE_LIKE_INDEXES | CREATE_TABLE_LIKE_IDENTITY | CREATE_TABLE_LIKE_STATISTICS);
- 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);
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ GetUserId(),
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
/*
* Open the new partition with no lock, because we already have
* AccessExclusiveLock placed there after creation.
*/
- newRel = table_openrv(newPartName, NoLock);
+ newRel = table_open(newRelId, NoLock);
/*
* We intended to create the partition with the same persistence as the
@@ -21458,6 +21642,9 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel,
errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
RelationGetRelationName(modelRel))));
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
return newRel;
}
@@ -21555,7 +21742,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
Relation newPartRel;
- newPartRel = createPartitionTable(sps->name, rel, context);
+ newPartRel = createPartitionTable(sps->name, rel);
newPartRels = lappend(newPartRels, newPartRel);
}
@@ -21799,7 +21986,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
}
/* Create table for new partition, use partitioned table as model. */
- newPartRel = createPartitionTable(cmd->name, rel, context);
+ newPartRel = createPartitionTable(cmd->name, rel);
/* Copy data from merged partitions to new partition. */
moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index cad830dc39..05cd4f4256 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,12 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
+ bool is_enforced, bool is_validated, bool is_local,
+ int16 inhcount, bool is_no_inherit, bool is_internal);
+
+extern void SetRelationNumChecks(Relation rel, int numchecks);
+
extern void RelationClearMissing(Relation rel);
extern void SetAttrMissing(Oid relid, char *attname, char *value);
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 0128f53d93..a47a635e50 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1584,6 +1584,65 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
(PARTITION tp_0 FOR VALUES FROM (0) TO (1),
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
RESET search_path;
--
DROP SCHEMA partition_split_schema;
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index ef5ea07f74..e185458e4e 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -955,6 +955,27 @@ ALTER TABLE t SPLIT PARTITION tp_0 INTO
PARTITION tp_1 FOR VALUES FROM (1) TO (2));
DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
RESET search_path;
--
--
2.40.1.windows.1
Hi, Dmitry!
On Tue, Jan 28, 2025 at 1:15 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Only patches v34-0001 and 2 has been tested.
Patch v34-0003-Refactor-createPartitionTable-to-remove-ProcessU.patch
do not apply anymore on src/backend/catalog/heap.cThanks, rebased.
The patches are attached to the email.
Thank you for the rebase.
I don't think we need a separate 0003 patch with refactoring. It's
probably good idea to keep this functionality as a separate patch, but
let's make then it a 0001, which prepares functions used by 0002 and
0003.
------
Regards,
Alexander Korotkov
Supabase
Hi!
I'd like to share some thoughts on which particular way this patch could go.
On Thu, Aug 22, 2024 at 8:25 PM Robert Haas <robertmhaas@gmail.com> wrote:
Here, aside from the name lookup issues, there are also problems with
expression evaluation: we can't split partitions without reindexing
rows that those partitions contain, and it is critical to think
through which is going to do the evaluation and make sure it's
properly sandboxed. I think we might need
SECURITY_RESTRICTED_OPERATION here.
+1 for use SECURITY_RESTRICTED_OPERATION
Another thing I want to highlight if you do have another go at this
patch is that it's really critical to think about where every single
property of the newly-created tables comes from. The original patch
didn't consider relpersistence or tableam, and here I just discovered
that owner is also an issue that probably needs more consideration,
but it goes way beyond that. For example, I was surprised to discover
that if I put per-partition constraints or triggers on a partition and
then split it, they were not duplicated to the new partitions. Now,
maybe that's actually the behavior we want -- I'm not 100% positive --
but it sure wasn't what I was expecting. If we did duplicate them when
splitting, then what's supposed to happen when merging occurs? That is
not at all obvious, at least to me, but it needs careful thought. ACLs
and rules and default values and foreign keys (both outbond and
inbound) all need to be considered too, along with 27 other things
that I'm sure I'm not thinking about right now. Some of this behavior
should probably be explicitly documented, but all of it should be
considered carefully enough before commit to avoid surprises later. I
say that both from a security point of view and also just from a user
experience point of view. Even if things aren't insecure, they can
still be annoying, but it's not uncommon in cases like this for
annoying things to turn out to also be insecure.
Yes, I think it's a good idea to duplicate dependent objects of split
partition to new partitions. But it important to very carefully check
user have relevant permissions for all of them. We could also provide
a syntax to exclude some of them (and even define new ones?), but I
strongly suspect that would overcomplicate patch for now and we need
to postpone this.
Regarding the merge, I think it would be good to provide a syntax to
let user choose a model partition between partitions to be merged.
Finally, if you do revisit this, I believe it would be a good idea to
think a bit harder about how data is moved around. My impression (and
please correct me if I am mistaken) is that currently, any split or
merge operation rewrites all the data in the source partition(s). If a
large partition is being split nearly equally, I think that has a good
chance of being optimal, but I think that might be the only case. If
we're merging partitions, wouldn't it be better to adjust the
constraints on the first partition -- or perhaps the largest partition
if we want to be clever -- and insert the data from all of the others
into it? Maybe that would even have syntax that puts the user in
control of which partition survives, e.g. ALTER TABLE tab1 MERGE
PARTITION part1 WITH part2, part3, .... That would also make it really
obvious to the user what all of the properties of part1 will be after
the merge: they will be exactly the same as they were before the
merge, except that the partition constraint will have been adjusted.
You basically dodge everything in the previous paragraph in one shot,
and it seems like it would also be faster. Splitting there's no
similar get-out-of-jail free card, at least not that I can see. Even
if you add syntax that splits a partition by using INSERT/DELETE to
move some rows to a newly-created partition, you still have to make at
least one new partition. But possibly that syntax is worth having
anyway, because it would be a lot quicker in the case of a highly
asymmetric split. On the other hand, maybe even splits are much more
likely and we don't really need it. I don't know.
Hmm... I think the important aspect for this DDL operation is to be
atomic and transactional. And that seems to be extremely hard to
achieve if we move the data between existing relnodes. How can we
rollback or recover after error? So, it least for initial
implementation I would leave data movement as it is.
------
Regards,
Alexander Korotkov
Supabase
On Mon, Dec 9, 2024 at 11:01 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
I see fixes for the issues mentioned in [1] and [2] are still not
implemented. Do you plan to do this in this release cycle?I would like to make some changes, but I think it would be appropriate
to discuss these points first.
As far as I understand, there is currently no clear opinion on how to
implement [1] and [2].I would appreciate your opinions on what improvements are really needed
and in what order they should be implemented.
Please, check my thoughts on how this patch could be further
developed. Given amount of work to be done, I doubt that'a a subject
for pg18. But I think you could continue this work, and we could
consider it for early pg19 cycle.
Links.
1. /messages/by-id/CAPpHfdtSxrcxQERO82cyQ2heN3+A7VC63k8SmL=EEiph-8rfHg@mail.gmail.com
2. /messages/by-id/CAPpHfdvVMdUX0DGSK3oAbt9C5TPup=BEq8QkmvDrMbuD4BR9Fw@mail.gmail.com
------
Regards,
Alexander Korotkov
Supabase
Hi, Alexander!
Thanks for your advices and recommendations!
I don't think we need a separate 0003 patch with refactoring. It's
probably good idea to keep this functionality as a separate patch, but
let's make then it a 0001, which prepares functions used by 0002 and
0003.
Done. 0003 was created separately to better understand what changes were
made after the verified changes 0001 and 0002.
Please, check my thoughts on how this patch could be further
developed. Given amount of work to be done, I doubt that'a a subject
for pg18. But I think you could continue this work, and we could
consider it for early pg19 cycle.
Good. I'll try to collect and summarize the opinions of colleagues on
these issues [1]/messages/by-id/CAPpHfdtSxrcxQERO82cyQ2heN3+A7VC63k8SmL=EEiph-8rfHg@mail.gmail.com, and then put them up for discussion in this thread.
Links.
[1]: /messages/by-id/CAPpHfdtSxrcxQERO82cyQ2heN3+A7VC63k8SmL=EEiph-8rfHg@mail.gmail.com
/messages/by-id/CAPpHfdtSxrcxQERO82cyQ2heN3+A7VC63k8SmL=EEiph-8rfHg@mail.gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v36-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v36-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From bcef7618e89ef60483a85853f4bba83bd4416dc6 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v36 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 88 +-
src/backend/catalog/heap.c | 8 +-
src/backend/commands/tablecmds.c | 603 ++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 6 +
src/include/nodes/parsenodes.h | 14 +
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 | 947 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 2901 insertions(+), 30 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7ff39ae8c6..7f4282504b 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4418,6 +4418,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index f9576da435..a2e4e37034 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1118,14 +1121,85 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1368,7 +1442,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1786,6 +1861,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 57ef466acc..1476d0ec04 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -101,9 +101,6 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
-static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
- bool is_enforced, bool is_validated, bool is_local,
- int16 inhcount, bool is_no_inherit, bool is_internal);
static void StoreConstraints(Relation rel, List *cooked_constraints,
bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
@@ -111,7 +108,6 @@ static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *
bool is_enforced,
bool is_initially_valid,
bool is_no_inherit);
-static void SetRelationNumChecks(Relation rel, int numchecks);
static Node *cookConstraint(ParseState *pstate,
Node *raw_constraint,
char *relname);
@@ -2065,7 +2061,7 @@ SetAttrMissing(Oid relid, char *attname, char *value)
*
* The OID of the new constraint is returned.
*/
-static Oid
+Oid
StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal)
@@ -3065,7 +3061,7 @@ AddRelationNotNullConstraints(Relation rel, List *constraints,
* relcache entries for the rel. Also, this backend will rebuild its
* own relcache entry at the next CommandCounterIncrement.
*/
-static void
+void
SetRelationNumChecks(Relation rel, int numchecks)
{
Relation relrel;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 18f64db6e3..1bd9cb10b7 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -701,6 +701,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4789,6 +4791,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5222,6 +5228,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5616,6 +5627,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);
@@ -6600,6 +6619,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:
@@ -19183,6 +19204,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19386,23 +19438,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -21034,3 +21071,535 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ (void) StoreAttrDefault(newRel, num, def, true, false);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ /* We can skip validation, since the new table should be empty. */
+ (void) StoreRelCheck(newRel, ccname, ccbin_node, ccenforced, true,
+ true, 0, ccnoinherit, false);
+ }
+
+ /* Update the count of constraints in the relation's pg_class tuple. */
+ SetRelationNumChecks(newRel, constr->num_check);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ GetUserId(),
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index d7f9c00c40..f2787452e6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17871,6 +17889,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18496,6 +18515,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ca028d2a66..5754a97683 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3485,6 +3488,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3762,6 +3875,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 81cbf10aa2..5c1393232a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,6 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2951,6 +2952,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index cad830dc39..05cd4f4256 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,12 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
+ bool is_enforced, bool is_validated, bool is_local,
+ int16 inhcount, bool is_no_inherit, bool is_internal);
+
+extern void SetRelationNumChecks(Relation rel, int numchecks);
+
extern void RelationClearMissing(Relation rel);
extern void SetAttrMissing(Oid relid, char *attname, char *value);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ffe155ee20..36e53ef300 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -948,6 +948,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -956,6 +967,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2463,6 +2476,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 cf2917ad07..a0b21ced88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -336,6 +336,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..7a960fed8f
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,947 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1edd9e45eb..71a5d73143 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9a3bee93de..b8ac4a92eb 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2682,6 +2682,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v36-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v36-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 32630a6b63cffcc1033aaa600462db26f35b8739 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v36 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 399 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1649 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 983 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4184 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7f4282504b..a059e85090 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index a2e4e37034..98ce143dbb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1121,6 +1125,56 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1199,7 +1253,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1443,7 +1498,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1861,6 +1916,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1bd9cb10b7..eb30791580 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -701,6 +701,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4791,6 +4794,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5228,6 +5235,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5627,6 +5639,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6619,6 +6639,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -21072,6 +21094,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -21359,6 +21632,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f2787452e6..d43e3f2791 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17958,6 +17992,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18596,6 +18631,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 5754a97683..9f86c4f056 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3867,7 +3901,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3875,6 +3909,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3883,7 +3918,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4316,13 +4355,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4331,9 +4370,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4341,7 +4380,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..9a3a281c84 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 54dad97555..249fa70234 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13618,3 +13618,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 5c1393232a..9d37fc9317 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2685,7 +2685,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2941,10 +2941,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2952,6 +2952,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 36e53ef300..3a88287b5d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2476,6 +2476,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a0b21ced88..1c03c74f1c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -420,6 +420,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index aa7a8a3800..52bd8aa51e 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -49,4 +49,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..a47a635e50
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1649 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 71a5d73143..9bf7c37202 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..e185458e4e
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,983 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index b8ac4a92eb..1c9b5df9ad 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2746,6 +2746,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
--- a/src/backend/catalog/heap.c +++ b/src/backend/catalog/heap.c @@ -101,9 +101,6 @@ static ObjectAddress AddNewRelationType(const char *typeName, Oid new_row_type, Oid new_array_type); static void RelationRemoveInheritance(Oid relid); -static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr, - bool is_enforced, bool is_validated, bool is_local, - int16 inhcount, bool is_no_inherit, bool is_internal); static void StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal); static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr, @@ -111,7 +108,6 @@ static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node * bool is_enforced, bool is_initially_valid, bool is_no_inherit); -static void SetRelationNumChecks(Relation rel, int numchecks);
I'm wary of taking some static functions and making them non-static
without further analysis, because we create a kind-of API that's
possible incoherent or at least incomplete and may cause trouble later.
Maybe we should make some effort to construct a real interface here.
For example, perhaps you don't need to expose both StoreRelCheck and
SetRelationNumChecks, but instead would be better served by exposing
StoreConstraints? (Though I think we need some explicit check that that
function requires that the table is new and has no constraint, otherwise
SetRelationNumChecks stores the wrong thing. No?) Or maybe use
AddRelationNewConstraints() instead, which is an already exposed function.
What I'm saying is just that we should be more watchful of what we put
in our .h files.
Note: I didn't actually review the patch.
--
Álvaro Herrera PostgreSQL Developer — https://www.EnterpriseDB.com/
On Mon, 3 Feb 2025 at 21:08, Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi, Alexander!
Thanks for your advices and recommendations!I don't think we need a separate 0003 patch with refactoring. It's
probably good idea to keep this functionality as a separate patch, but
let's make then it a 0001, which prepares functions used by 0002 and
0003.Done. 0003 was created separately to better understand what changes were
made after the verified changes 0001 and 0002.Please, check my thoughts on how this patch could be further
developed. Given amount of work to be done, I doubt that'a a subject
for pg18. But I think you could continue this work, and we could
consider it for early pg19 cycle.Good. I'll try to collect and summarize the opinions of colleagues on
these issues [1], and then put them up for discussion in this thread.
I noticed that Alvaro's comments from [1]/messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql have not yet been addressed,
I have changed the status of commitfest entry to "Waiting on Author",
please address them and update it to "Needs review".
[1]: /messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql
Regards,
Vignesh
I noticed that Alvaro's comments from [1] have not yet been addressed,
Thanks!
I'm sorry, I missed this comment.
I'm wary of taking some static functions and making them non-static
...
For example, perhaps you don't need to expose both StoreRelCheck and
SetRelationNumChecks, but instead would be better served by exposing
StoreConstraints? ... Or maybe use AddRelationNewConstraints() ...
I replaced explosion of functions StoreRelCheck + SetRelationNumChecks
to StoreConstraints explosion. Probably function
AddRelationNewConstraints is not very suitable for this ...
[1]: /messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql
/messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v37-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v37-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From aa0d98d5a964564f1ba2d3d2f3d85ae1498c293e Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v37 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 88 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 617 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 14 +
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 | 947 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 609 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 2911 insertions(+), 27 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index cdb1a07e9d..0f01dc3cd9 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4442,6 +4442,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 4f15b89a98..3d059813c5 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1144,14 +1147,85 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1394,7 +1468,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1818,6 +1893,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index bd3554c0bf..39ae742cb8 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 129c97fdf2..4b474a190a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -711,6 +711,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4805,6 +4807,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5240,6 +5246,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5636,6 +5647,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);
@@ -6620,6 +6639,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:
@@ -19498,6 +19519,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -19701,23 +19753,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -21349,3 +21386,549 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel)
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ GetUserId(),
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ newPartRel = createPartitionTable(cmd->name, rel);
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 271ae26cba..cdd5d590d7 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17906,6 +17924,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18532,6 +18551,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index abbe1bb45a..222612cd9e 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3501,6 +3504,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3778,6 +3891,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8432be641a..78469c7d6c 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2714,6 +2714,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2980,6 +2981,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 23c9e3c5ab..9805b68ba5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -948,6 +948,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -956,6 +967,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2463,6 +2476,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 40cf090ce6..dd607d9896 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -336,6 +336,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 143109aa4d..c1499338d6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -106,6 +106,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..7a960fed8f
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,947 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 37b6d21e1f..379b961199 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 predicate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bede819af9
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,609 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 93339ef3c5..347a2b4e15 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2709,6 +2709,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SlabBlock
--
2.40.1.windows.1
v37-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v37-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 74d7dfada57d58b64884c176d426629bcf531914 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v37 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 77 +-
src/backend/commands/tablecmds.c | 399 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1649 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 983 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4184 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 0f01dc3cd9..1c35baea9a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4463,6 +4463,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 3d059813c5..66203c0683 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1147,6 +1151,56 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1225,7 +1279,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1469,7 +1524,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1893,6 +1948,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4b474a190a..a01ee0a4c7 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -711,6 +711,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4807,6 +4810,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5246,6 +5253,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5647,6 +5659,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6639,6 +6659,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -21387,6 +21409,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -21688,6 +21961,132 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index cdd5d590d7..7299f16cbf 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17993,6 +18027,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18632,6 +18667,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 222612cd9e..2dea1c6d2f 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3542,6 +3542,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3883,7 +3917,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3891,6 +3925,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3899,7 +3934,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4332,13 +4371,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4347,9 +4386,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4357,7 +4396,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..9a3a281c84 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 9e90acedb9..6f40c02109 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13697,3 +13697,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 78469c7d6c..0bb693e63d 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2714,7 +2714,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2970,10 +2970,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2981,6 +2981,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 9805b68ba5..cd3e854d47 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2476,6 +2476,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index dd607d9896..6b4f65d313 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -420,6 +420,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index c1499338d6..6da98cffac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..a47a635e50
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1649 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 379b961199..21c1fa730a 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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..e185458e4e
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,983 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 347a2b4e15..5d25679129 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2774,6 +2774,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi!
We (with colleagues) discussed further improvements to SPLIT/MERGE
PARTITION(S). As a result of the discussion, the following answers to
the questions remained:
1. Who should be the owner of new partitions (SPLIT PARTITION command)
if owner of the partition being split is not the same as the current user?
a) current user (since he is the one who creates new tables);
b) the owner of the partitioned partition (since it is the owner of the
table and should continue to own it).
2. Who should be the owner of the new partition (MERGE PARTITIONS
command) if the partitions being merged have different owners?
a) current user (since he is the one who creates new table);
b) merging of partitions should be forbidden if they have different owners.
Please, advise what seems to be the best solution for points 1 and 2.
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Hi!
Changes in patches:
1) Added usage of SECURITY_RESTRICTED_OPERATION for SPLIT/MERGE
PARTITION(S) commands.
2) For SPLIT PARTITION command: new partitions will have the same owner
as the parent.
3) For MERGE PARTITIONS command: if merged partitions have different
owners, an error will be generated.
Patches are attached to the email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v38-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v38-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 52344bea006e5bd8d4329f89473525e0f1ff59ba Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v38 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 91 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 654 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 14 +
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 | 985 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 642 ++++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 3022 insertions(+), 27 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..93d28ad058 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,88 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1474,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1908,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 54ad38247a..dc44dd4053 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20143,6 +20164,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20346,23 +20398,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22001,3 +22038,586 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners")));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..374ce5432a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..94c0f431e8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3878,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..5ec57e3edd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -948,6 +948,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -956,6 +967,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2468,6 +2481,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..42d6e8c781
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,985 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..d862a62741
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,642 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9ea573fae2..20428af1b6 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2764,6 +2764,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
--
2.40.1.windows.1
v38-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v38-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From b98bb33957a303756621e4a38b509b7121730a2e Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v38 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 80 +-
src/backend/commands/tablecmds.c | 422 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1715 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1043 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4336 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 93d28ad058..cca1090e27 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,59 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1231,7 +1288,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1475,7 +1533,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1908,6 +1966,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dc44dd4053..0044a6485e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22039,6 +22061,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22342,6 +22615,155 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 374ce5432a..1f14aa1d70 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 94c0f431e8..85b159b3c6 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3870,7 +3904,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3878,6 +3912,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3886,7 +3921,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4321,13 +4360,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4336,9 +4375,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4346,7 +4385,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..9a3a281c84 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 5ec57e3edd..ddd0f71a22 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2481,6 +2481,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..2c1db143ef
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1715 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..385e02e123
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1043 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 20428af1b6..43f27ddee6 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2831,6 +2831,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Mon, May 12, 2025 at 4:31 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
We (with colleagues) discussed further improvements to SPLIT/MERGE
PARTITION(S). As a result of the discussion, the following answers to
the questions remained:1. Who should be the owner of new partitions (SPLIT PARTITION command)
if owner of the partition being split is not the same as the current user?
a) current user (since he is the one who creates new tables);
b) the owner of the partitioned partition (since it is the owner of the
table and should continue to own it).
per https://www.postgresql.org/docs/current/sql-altertable.html
"You must own the table to use ALTER TABLE."
That means the current user must own the to be SPLITed partition.
the new partitions owner should be current user (the one who did ALTER TABLE)
2. Who should be the owner of the new partition (MERGE PARTITIONS
command) if the partitions being merged have different owners?
a) current user (since he is the one who creates new table);
b) merging of partitions should be forbidden if they have different owners.
let say:
alter table whatever_range merge partitions
( whatever_range_c, whatever_range_de )
into whatever_range_cde;
In this case, the current user must own
whatever_range_c and whatever_range_de to perform this operation.
and the current user will be the owner of whatever_range_cde.
Hi!
per https://www.postgresql.org/docs/current/sql-altertable.html
"You must own the table to use ALTER TABLE."
That means the current user must own the to be SPLITed partition.
Last statement may be incorrect (if the logic is different).
Current user can attach another user's partition. If current user can
change (attach) another user's partition, why can't he split the
partition? After attach, partition is part of current user's table, and
current user can change his own table. (Moreover, the owner of the new
partitions is the same as the owner of the split partition.)
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Wed, May 21, 2025 at 8:30 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
per https://www.postgresql.org/docs/current/sql-altertable.html
"You must own the table to use ALTER TABLE."
That means the current user must own the to be SPLITed partition.Last statement may be incorrect (if the logic is different).
Current user can attach another user's partition. If current user can
change (attach) another user's partition, why can't he split the
partition? After attach, partition is part of current user's table, and
current user can change his own table. (Moreover, the owner of the new
partitions is the same as the owner of the split partition.)--
I think if he can attach another partition, then he can split the partition.
currently ALTER TABLE ATTACH PARTITION requires the current user
both own the partitioned table and the to be attached partition.
for example:
begin;
create role alice;
create role bob;
GRANT all privileges on schema public to alice;
GRANT all privileges on schema public to bob;
set role bob;
create table at_partitioned (a int, b text) partition by range (a);
set role alice;
create table at_part_2 (b text, a int);
set role bob;
alter table at_partitioned attach partition at_part_2 for values from
(1000) to (2000); --should error
rollback;
----------------
begin;
create role alice;
create role bob;
GRANT all privileges on schema public to alice;
GRANT all privileges on schema public to bob;
set role bob;
create table at_partitioned (a int, b text) partition by range (a);
set role alice;
create table at_part_2 (b text, a int);
alter table at_partitioned attach partition at_part_2 for values from
(1000) to (2000); --should error
rollback;
P.S. maybe using sql examples can illustrate the idea more intuitively,
sometimes words may cause confusion.
for example:
...
If in both examples you replace
create role bob;
with
create role bob SUPERUSER;
and in the second example add "set role bob;" before "alter table ..."
query, then no error will be occur.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Thu, May 22, 2025 at 1:01 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
for example:
...If in both examples you replace
create role bob;
with
create role bob SUPERUSER;
and in the second example add "set role bob;" before "alter table ..."
query, then no error will be occur.
That is fine.
superuser can bypass all permission checks.
superuser can attach any table to the partitioned table as he wants.
for example:
begin;
create role alice SUPERUSER;
create role bob SUPERUSER;
GRANT all privileges on schema public to alice;
GRANT all privileges on schema public to bob;
set role bob;
create table at_partitioned (a int, b text) partition by range (a);
set role alice;
create table at_part_2 (b text, a int);
set role bob;
alter table at_partitioned attach partition at_part_2 for values from
(1000) to (2000);
rollback;
Am I missing something?
superuser can bypass all permission checks.
superuser can attach any table to the partitioned table as he wants.
That's right.
Using SUPERUSER may be a rare situation, but it needs to be processed.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Thu, May 22, 2025 at 11:57 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
superuser can bypass all permission checks.
superuser can attach any table to the partitioned table as he wants.That's right.
Using SUPERUSER may be a rare situation, but it needs to be processed.
I suggest that owner of new partitions produced by ALTER TABLE ...
SPLIT should be the same as owner of original partition. Even if this
operation is done by superuser. Superuser may explicitly set he owner
if needed. I think we need to explicitly document this.
------
Regards,
Alexander Korotkov
Supabase
Hi, Dmitry!
On Tue, May 20, 2025 at 1:36 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Changes in patches:
1) Added usage of SECURITY_RESTRICTED_OPERATION for SPLIT/MERGE
PARTITION(S) commands.2) For SPLIT PARTITION command: new partitions will have the same owner
as the parent.3) For MERGE PARTITIONS command: if merged partitions have different
owners, an error will be generated.
Some notes to the patch.
1) I think we need explicitly document who is the owner of the new
partition(s). The documentation for MERGE command says all the merged
partitions should have the same owner. Good, but also we need to
state that the new partition should have the same owner. Same to the
SPLIT command.
2) I think we also need to describe what happens not just with
ownership, but with ACLs. We currently don't do anything to them, so
basically we discard existing ACLs. It's probably OK, and we could
introduce options for ACL handling later. But we need to state in the
docs that it's user responsibility to setup ACL on new partition(s).
------
Regards,
Alexander Korotkov
Supabase
Some notes to the patch. ...
Thanks for the notes!
I'll try to make edits in the next few days.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Added some changes to documentation.
Patches are attached to the email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v39-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v39-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From dfccd47d858ad71b4d0ce57ade3e629583efd7fa Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v39 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 96 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 654 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 126 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 14 +
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 | 985 ++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 642 ++++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 3027 insertions(+), 27 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..72bb53b084 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,93 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1479,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1913,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index acf11e83c0..882fd89609 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20143,6 +20164,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20346,23 +20398,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22009,3 +22046,586 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel))));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel))));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session")));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel))));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners")));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname)));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..374ce5432a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,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 <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NULL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..94c0f431e8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,116 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel))));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is 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;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3878,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index dd00ab420b..a0546fde2d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -953,6 +953,17 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
@@ -961,6 +972,8 @@ 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 MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2486,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..42d6e8c781
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,985 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..d862a62741
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,642 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Helsinki', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Oslo', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..2038603c08 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
--
2.40.1.windows.1
v39-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v39-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From be49803869d1a65da4c8150eb41810628e619719 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v39 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 84 +-
src/backend/commands/tablecmds.c | 422 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 1 +
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1715 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1043 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4340 insertions(+), 17 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 72bb53b084..01e2937092 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,63 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1236,7 +1297,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1480,7 +1542,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1913,6 +1975,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 882fd89609..f9dad4ee50 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22047,6 +22069,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel)));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22350,6 +22623,155 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname)));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 374ce5432a..1f14aa1d70 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 94c0f431e8..85b159b3c6 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, NoLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3870,7 +3904,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3878,6 +3912,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3886,7 +3921,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items")));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4321,13 +4360,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4336,9 +4375,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4346,7 +4385,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..9a3a281c84 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location)));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location)));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location)));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal))));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one")),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split")));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT")),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists")),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ (errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname)),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index a0546fde2d..cc9cb8ac42 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2486,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..2c1db143ef
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1715 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+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');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..385e02e123
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1043 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+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_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10);
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (19, 'Ivanov');
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+INSERT INTO sales VALUES (1, 100, '2022-03-01');
+INSERT INTO sales VALUES (1, 110, '2022-03-02');
+INSERT INTO sales VALUES (10, 150, '2022-03-01');
+INSERT INTO sales VALUES (10, 90, '2022-03-03');
+INSERT INTO sales VALUES (19, 200, '2022-03-04');
+INSERT INTO sales VALUES (20, 50, '2022-03-12');
+INSERT INTO sales VALUES (20, 170, '2022-03-02');
+INSERT INTO sales VALUES (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May');
+INSERT INTO salespeople (salesperson_name) VALUES ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES ('dummy value 1', 19, 100, now(), 'Ivanov');
+INSERT INTO salespeople10_40 VALUES ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES (1, 'Poirot');
+INSERT INTO salespeople VALUES (10, 'May');
+INSERT INTO salespeople VALUES (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Bejing', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'New York', 500, '2022-03-03');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Warsaw', 750, '2022-03-04');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Lisbon', 250, '2022-03-07');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Berlin', 1000, '2022-03-01');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-06');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Oslo', 1200, '2022-03-11');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Helsinki', 800, '2022-03-02');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Madrid', 650, '2022-03-05');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Kyiv', 350, '2022-03-10');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Warsaw', 150, '2022-03-08');
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31');
+INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-09');
+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-07');
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+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');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 2038603c08..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2827,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Wed, Jun 4, 2025 at 4:53 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Added some changes to documentation.
Patches are attached to the email.
hi.
I haven't touched v39-0002 yet.
The following are reviews of v39-0001.
+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');
you can put it into one INSERT. like
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'),
(1, 'May', 1000, '2022-01-31');
which can make the regress test faster.
(apply the logic to other places in src/test/regress/sql/partition_merge.sql)
+ 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")));
This error case doesn't seem to have a related test, and adding one
would be great.
per
https://www.postgresql.org/docs/current/error-message-reporting.html
"The extra parentheses were required before PostgreSQL version 12, but
are now optional."
so now you can remove the extra parentheses.
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be merged"));
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel))));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel))));
we can make the first error message like the second one.
errmsg("\"%s\" is not a partition of \"%s\"....)
+ 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 contain at least two items")));
This also seems to have no tests.
adding a dummy one should be ok.
We added List *partlist into PartitionCmd
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 MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
then in src/backend/parser/gram.y
we should use
cmd->partlist = NIL;
instead of
cmd->partlist = NULL;
We also need comments explaining PartitionCmd.name
meaning for ALTER TABLE MERGE PARTITIONS INTO?
transformPartitionCmdForMerge
+ partOid = RangeVarGetRelid(name, NoLock, false);
here "NoLock" seems not right?
For example, after "RangeVarGetRelid(name, NoLock, false);"
before checkPartition, I drop the table test.t in another session.
i got the following error:
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022, test.t) INTO sales_feb_mar_apr2022;
ERROR: could not open relation with OID 18164
Hi!
Thank you very much for review.
1.
you can put it into one INSERT. like
INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'),
(1, 'May', 1000, '2022-01-31');
which can make the regress test faster.
(apply the logic to other places in
src/test/regress/sql/partition_merge.sql)
Test changed.
2.
+ errmsg("partition of hash-partitioned table cannot be merged")));
This error case doesn't seem to have a related test, and adding one
would be great.
Added test for hash partitioned table.
3.
per
https://www.postgresql.org/docs/current/error-message-reporting.html
"The extra parentheses were required before PostgreSQL version 12, but
are now optional."
so now you can remove the extra parentheses.
Extra parentheses removed.
4.
we can make the first error message like the second one.
errmsg("\"%s\" is not a partition of \"%s\"....)
Error message
errmsg("relation \"%s\" is not a partition of relation \"%s\""
occurs in two more places in the code.
I think it's better to keep this error message (for consistency).
5.
+ errmsg("list of new partitions should contain at least two items")));
This also seems to have no tests.
adding a dummy one should be ok.
Test added.
6.
We added List *partlist into PartitionCmd
typedef struct PartitionCmd
we should use
cmd->partlist = NIL;
instead of
cmd->partlist = NULL;
We also need comments explaining PartitionCmd.name
meaning for ALTER TABLE MERGE PARTITIONS INTO?
Fixed.
7.
transformPartitionCmdForMerge
+ partOid = RangeVarGetRelid(name, NoLock, false);
here "NoLock" seems not right?
AccessExclusiveLock on partitioned table protects only the DEFAULT
partition. Fixed.
P.S. Similar changes were made for the second commit with SPLIT PARTITION.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v40-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v40-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 84dc4d6bdb850b6f13590a80d573b000b8d91e29 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v40 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 96 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 654 ++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 129 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 16 +-
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 | 1003 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 662 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 3069 insertions(+), 28 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..72bb53b084 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,93 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1479,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1913,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index acf11e83c0..b4ec6691d8 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20143,6 +20164,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20346,23 +20398,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22009,3 +22046,586 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, NULL);
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid namespaceId;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up the namespace in which we are supposed to create the partition,
+ * check we have permission to create there, lock it against concurrent
+ * drop, and mark stmt->relation as RELPERSISTENCE_TEMP if a temporary
+ * namespace is selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, NULL);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ existingRelid = get_relname_relid(cmd->name->relname, namespaceId);
+
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..47823ef7a5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..0d3ab35a57 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,119 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3881,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index dd00ab420b..230a42b966 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -953,14 +953,27 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2486,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..a24874798d
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1003 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..c53ac5a199
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,662 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..2038603c08 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
--
2.40.1.windows.1
v40-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v40-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 8198249ebf4f4dc19fd0cfd6576d8ccbf3eb292b Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v40 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 84 +-
src/backend/commands/tablecmds.c | 422 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 3 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1741 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1070 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4394 insertions(+), 18 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 72bb53b084..01e2937092 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,63 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1236,7 +1297,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1480,7 +1542,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1913,6 +1975,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b4ec6691d8..58e95c65fc 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22047,6 +22069,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22350,6 +22623,155 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ Oid namespaceId;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existing_relid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up the namespace in which we are supposed to create the
+ * partition, check we have permission to create there, lock it
+ * against concurrent drop, and mark stmt->relation as
+ * RELPERSISTENCE_TEMP if a temporary namespace is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, NULL);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ existing_relid = get_relname_relid(relname, namespaceId);
+ if (existing_relid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (existing_relid != InvalidOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 47823ef7a5..750f531b81 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 0d3ab35a57..510f854def 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3873,7 +3907,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3881,6 +3915,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3889,7 +3924,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4324,13 +4363,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4339,9 +4378,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4349,7 +4388,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..42146c3bfa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 230a42b966..bbd1110a40 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -970,7 +970,7 @@ typedef struct SinglePartitionSpec
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
@@ -2486,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..51886c66b4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1741 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..682a83793a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1070 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: all partitions in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 2038603c08..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2827,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi Dmitry!
On Wed, Jun 4, 2025 at 10:44 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thank you very much for review.
Thank you for your work on this patch. I have some additional notes on
this patch.
Why don't you use *existing_relation_id argument of
RangeVarGetAndCheckCreationNamespace(), when it is called from
createPartitionTable() and ATExecSplitPartition()? This argument provide
an elegant way to find a duplicate table with the same name.
It also seems that 0002 patch has the following error message, which aren't
experienced in the regression tests.
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not
equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value
because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split
partition does",
+ searchNull ? "NULL" :
get_list_partvalue_string(notFoundVal)));
+ ereport(ERROR,
+
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be
one"),
+ parser_errposition(pstate,
sps->name->location));
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because
split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *)
linitial(partlist))->name->location));
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT
partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition
row"),
+ errtable(splitRel));
------
Regards,
Alexander Korotkov
Supabase
hi.
the following are review of
v40-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022) INTO sales_feb_mar_apr2022;
There are no tests when sales_feb2022 or sales_mar2022 have any constraints.
a partition can have its own constraint.
What should we do when any to be merged partition has constraints?
----------------------------------------------------------------
DROP TABLE IF EXISTS sales_range cascade;
CREATE TABLE sales_range (salesperson_id INT, salesperson_name text,
sales_amount INT generated always as (1) stored, sales_date DATE)
PARTITION BY RANGE (sales_date);
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');
ALTER TABLE sales_feb2022 ALTER COLUMN sales_amount SET EXPRESSION AS (10);
ALTER TABLE sales_mar2022 ALTER COLUMN sales_amount SET EXPRESSION AS (20);
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022) INTO sales_feb_mar2022;
with v40, sales_feb_mar2022 column sales_int generated expression is
(generated always as (1) stored)
maybe this is what we expected.
but we should have some tests on it.
----------------------------------------------------------------
DROP TABLE IF EXISTS sales_range cascade;
CREATE TABLE sales_range (salesperson_id INT, salesperson_name text,
sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
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 VIEW x AS SELECT * FROM sales_mar2022;
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022) INTO sales_feb_mar2022;
ERROR: cannot drop table public.sales_mar2022 because other objects
depend on it
DETAIL: view public.x depends on table public.sales_mar2022
HINT: Use DROP ... CASCADE to drop the dependent objects too.
Maybe this is expected, but we need to mention it somewhere and have
some tests on it.
saying that MERGE PARTITIONS will effectively drop the partitions, so
if any object depends on that partition
then MERGE PARTITIONS can not be done.
----------------------------------------------------------------
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another
session"));
Looking at it, modelRel is the partitioned table we called ALTER TABLE.
for example:
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022) INTO sales_feb_mar2022;
modelRel is sales_range.
so this error check can be performed as early as the
transformPartitionCmdForMerge stage?
----------------------------------------------------------------
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ?
modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
looking at the output of "select * from pg_am;".
i think, we can do the following way:
if (modelRel->rd_rel->relam)
elog(ERROR, "error");
relamId = modelRel->rd_rel->relam;
----------------------------------------------------------------
Attached is some refactoring in moveMergedTablesRows, hope it's straightforward.
for example:
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
execute_attr_map_slot will call "slot_getallattrs(srcslot);" so the
first one is unncessary.
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
can change to
srcslot = table_slot_create(mergingPartition, NULL);
Attachments:
v40-minor_refactor_moveMergedTablesRows.no_cfbotapplication/octet-stream; name=v40-minor_refactor_moveMergedTablesRows.no_cfbotDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b4ec6691d8f..9e1ac1e6235 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22373,9 +22373,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
bistate = GetBulkInsertState();
/* Create necessary tuple slot. */
- dstslot = MakeSingleTupleTableSlot(RelationGetDescr(newPartRel),
- table_slot_callbacks(newPartRel));
- ExecStoreAllNullTuple(dstslot);
+ dstslot = table_slot_create(newPartRel, NULL);
foreach(listptr, mergingPartitionsList)
{
@@ -22386,8 +22384,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
Snapshot snapshot;
/* Create tuple slot for new partition. */
- srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
- table_slot_callbacks(mergingPartition));
+ srcslot = table_slot_create(mergingPartition, NULL);
/*
* Map computing for moving attributes of merged partition to new
@@ -22404,8 +22401,7 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
{
TupleTableSlot *insertslot;
- /* Extract data from old tuple. */
- slot_getallattrs(srcslot);
+ CHECK_FOR_INTERRUPTS();
if (tuple_map)
{
@@ -22414,6 +22410,8 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
}
else
{
+ slot_getallattrs(srcslot);
+
/* Copy attributes directly. */
insertslot = dstslot;
@@ -22430,8 +22428,6 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
/* Write the tuple out to the new relation. */
table_tuple_insert(newPartRel, insertslot, mycid,
ti_options, bistate);
-
- CHECK_FOR_INTERRUPTS();
}
table_endscan(scan);
hi.
bug in transformPartitionCmdForMerge "equal(name, name2))"
+static void
+transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
public.sales_feb2022) INTO sales_feb_mar2022;
ERROR: lower bound of partition "sales_feb2022" conflicts with upper
bound of previous partition "sales_feb2022"
in this context. "sales_feb2022" is the same as "public.sales_feb2022".
hi.
When using ALTER TABLE ... MERGE PARTITIONS, some of the new
partition's properties will
not be inherited from to be merged partitions; instead, they will be directly
copied from the root partitioned table.
so we need to test this behavior.
The attached test file is for test table properties:
(COMMENTS, COMPRESSION, DEFAULTS, GENERATED, STATISTICS, STORAGE).
STATISTICS: to be merged partition's STATISTICS will be dropped.
COMMENTS: to be merged partition's COMMENTS will be dropped.
Attachments:
v40-0001-test-for-MERGE-PARTITION.no-cfbotapplication/octet-stream; name=v40-0001-test-for-MERGE-PARTITION.no-cfbotDownload
From 4b7a5b7651eb79458139372eeebe55b0d84f49ea Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Thu, 5 Jun 2025 20:21:51 +0800
Subject: [PATCH v40 1/1] test for MERGE PARTITION
table property:
(COMMENTS, COMPRESSION, DEFAULTS, GENERATED, STATISTICS, STORAGE)
partition can differ from root partitioned table.
When using ALTER TABLE ... MERGE PARTITIONS, the new partition's properties will
not be inherited from to be merged partitions; instead, they will be directly
copied from the root partitioned table.
---
src/test/regress/expected/partition_merge.out | 50 +++++++++++++++++++
src/test/regress/sql/partition_merge.sql | 27 ++++++++++
2 files changed, 77 insertions(+)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index a24874798d8..e8428b5864c 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -8,6 +8,53 @@ SET search_path = partitions_merge_schema, public;
--
-- BY RANGE partitioning
--
+-- test merged new partition properties (COMMENTS, COMPRESSION, DEFAULTS,
+-- GENERATED, STATISTICS, STORAGE) be same as merged partitioned table.
+-- STATISTICS on to be merged partiton will be dropped.
+create table pp (
+ f1 int, f2 text storage main default 'pp',
+ f3 int, f4 date generated always as ('2022-01-01') stored) partition by range (abs(f1));
+create table pp_1 (
+ f1 int, f2 text storage external compression pglz default 'pp_1',
+ f3 int, f4 date generated always as ('2022-01-02') stored) with (fillfactor=70);
+create table pp_2 (
+ f1 int, f2 text storage extended compression lz4 default 'pp_2',
+ f3 int, f4 date generated always as ('2022-01-03') stored) with (fillfactor=10);
+alter table pp attach partition pp_1 for values from (-1) to (10);
+alter table pp attach partition pp_2 for values from (10) to (20);
+insert into pp(f1) values (-1), (1), (10), (11);
+create statistics pp_stat (dependencies) on f1, f3 from pp;
+create statistics pp_1_stat (dependencies) on f1, f3 from pp_1;
+create statistics pp_2_stat (dependencies) on f1, f3 from pp_2;
+comment on column pp_1.f1 is 'pp_1.f1';
+comment on column pp_2.f1 is 'pp_2 f1';
+comment on column pp.f1 is 'pp f1';
+\d+ pp_2
+ Table "partitions_merge_schema.pp_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ f1 | integer | | | | plain | | pp_2 f1
+ f2 | text | | | 'pp_2'::text | extended | |
+ f3 | integer | | | | plain | |
+ f4 | date | | | generated always as ('01-03-2022'::date) stored | plain | |
+Partition of: pp FOR VALUES FROM (10) TO (20)
+Partition constraint: ((abs(f1) IS NOT NULL) AND (abs(f1) >= 10) AND (abs(f1) < 20))
+Statistics objects:
+ "partitions_merge_schema.pp_2_stat" (dependencies) ON f1, f3 FROM pp_2
+Options: fillfactor=10
+
+ALTER TABLE pp MERGE PARTITIONS (pp_1, pp_2) INTO pp_2;
+\d+ pp_2
+ Table "partitions_merge_schema.pp_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ f1 | integer | | | | plain | |
+ f2 | text | | | 'pp'::text | main | |
+ f3 | integer | | | | plain | |
+ f4 | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: pp FOR VALUES FROM ('-1') TO (20)
+Partition constraint: ((abs(f1) IS NOT NULL) AND (abs(f1) >= '-1'::integer) AND (abs(f1) < 20))
+
--
-- Test for error codes
--
@@ -1000,4 +1047,7 @@ DROP TABLE t;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
+ERROR: cannot drop schema partitions_merge_schema because other objects depend on it
+DETAIL: table partitions_merge_schema.pp depends on schema partitions_merge_schema
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index c53ac5a1999..861bd186b56 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -11,6 +11,33 @@ SET search_path = partitions_merge_schema, public;
-- BY RANGE partitioning
--
+-- test merged new partition properties (COMMENTS, COMPRESSION, DEFAULTS,
+-- GENERATED, STATISTICS, STORAGE) be same as merged partitioned table.
+-- STATISTICS on to be merged partiton will be dropped.
+create table pp (
+ f1 int, f2 text storage main default 'pp',
+ f3 int, f4 date generated always as ('2022-01-01') stored) partition by range (abs(f1));
+create table pp_1 (
+ f1 int, f2 text storage external compression pglz default 'pp_1',
+ f3 int, f4 date generated always as ('2022-01-02') stored) with (fillfactor=70);
+create table pp_2 (
+ f1 int, f2 text storage extended compression lz4 default 'pp_2',
+ f3 int, f4 date generated always as ('2022-01-03') stored) with (fillfactor=10);
+
+alter table pp attach partition pp_1 for values from (-1) to (10);
+alter table pp attach partition pp_2 for values from (10) to (20);
+insert into pp(f1) values (-1), (1), (10), (11);
+
+create statistics pp_stat (dependencies) on f1, f3 from pp;
+create statistics pp_1_stat (dependencies) on f1, f3 from pp_1;
+create statistics pp_2_stat (dependencies) on f1, f3 from pp_2;
+comment on column pp_1.f1 is 'pp_1.f1';
+comment on column pp_2.f1 is 'pp_2 f1';
+comment on column pp.f1 is 'pp f1';
+\d+ pp_2
+ALTER TABLE pp MERGE PARTITIONS (pp_1, pp_2) INTO pp_2;
+\d+ pp_2
+
--
-- Test for error codes
--
--
2.34.1
Hi Alexander!
Thanks for your notes!
1.
Why don't you use *existing_relation_id argument of
RangeVarGetAndCheckCreationNamespace(), when it is called from
createPartitionTable() and ATExecSplitPartition()? This argument
provide an elegant way to find a duplicate table with the same name.
Code changed.
2.
It also seems that 0002 patch has the following error message, which
aren't experienced in the regression tests.
2a. Added tests for these error messages:
+errmsg("upper bound of partition \"%s\" is not equal to upper bound of
split partition",
+errmsg("new partition \"%s\" cannot have this value because split
partition does not have",
+errmsg("DEFAULT partition should be one"),
+errmsg("new partition cannot be DEFAULT because DEFAULT partition
already exists"),
2b. Tests for these error messages already exists:
+errmsg("new partitions do not have value %s but split partition does",
+errmsg("one partition in the list should be DEFAULT because split
partition is DEFAULT"),
2c. The error message
+errmsg("can not find partition for split partition row"),
cannot be reproduced using regression tests, because it is issued when
partition contains a record that should not be there (i.e. when the
database is corrupted).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v41-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v41-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 502ee25987a52ba02a248136a66157d5d9ddc42f Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v41 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 96 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 655 ++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 129 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 16 +-
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 | 1003 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 662 +++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 3070 insertions(+), 28 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..72bb53b084 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,93 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If DEFAULT partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If DEFAULT partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the DEFAULT partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1479,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1913,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 164ec56a59..5579b0ce01 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20166,6 +20187,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20369,23 +20421,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22032,3 +22069,587 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(mergingPartition),
+ table_slot_callbacks(mergingPartition));
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, 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 to 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..47823ef7a5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..0d3ab35a57 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,119 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3881,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index dd00ab420b..230a42b966 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -953,14 +953,27 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2486,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..a24874798d
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1003 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..c53ac5a199
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,662 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..2038603c08 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
--
2.40.1.windows.1
v41-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v41-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 1c1a37a268019739682dff33cc86fa47a5a61459 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v41 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 84 +-
src/backend/commands/tablecmds.c | 419 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 3 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1781 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1106 ++++++++++
src/tools/pgindent/typedefs.list | 1 +
20 files changed, 4467 insertions(+), 18 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 72bb53b084..01e2937092 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,63 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a DEFAULT partition, one of the new partitions must be DEFAULT.
+ In case one of the new partitions or one of existing partitions is DEFAULT,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have spaces
+ between partitions bounds. If the partitioned table does not have a DEFAULT
+ partition, the DEFAULT partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a DEFAULT partition and the partitioned table
+ does not have a DEFAULT partition, the following must be true: sum bounds of
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should be
+ equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a DEFAULT partition: we split it, but after
+ splitting we have a partition with the same name).
+ Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1236,7 +1297,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1480,7 +1542,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1913,6 +1975,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5579b0ce01..2861b8d742 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22070,6 +22092,257 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel),
+ table_slot_callbacks(pc->partRel));
+ ExecStoreAllNullTuple(pc->dstslot);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = MakeSingleTupleTableSlot(RelationGetDescr(splitRel),
+ table_slot_callbacks(splitRel));
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+
+ CHECK_FOR_INTERRUPTS();
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22378,6 +22651,152 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existingRelid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 47823ef7a5..750f531b81 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 0d3ab35a57..510f854def 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3873,7 +3907,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3881,6 +3915,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3889,7 +3924,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4324,13 +4363,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4339,9 +4378,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4349,7 +4388,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..42146c3bfa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 230a42b966..bbd1110a40 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -970,7 +970,7 @@ typedef struct SinglePartitionSpec
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
@@ -2486,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..9d471870e4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1781 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..1f7b592ba0
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1106 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 2038603c08..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2827,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi, jian he!
Thank you very much for your emails!
Unfortunately, due to urgent tasks at my work, I do not have time to
look through your notes today and tomorrow.
But I will definitely do it at the beginning of next week.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
hi.
one more patch for regress tests.
ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20,
salespeople20_30, salespeople30_40) INTO salespeople10_40;
the trigger on the merged partition will be dropped.
For example, here, trigger on salespeople10_20 will be dropped.
I am surprised that partition_merge.sql doesn't have much \d+ command.
so I added two, which is necessary IMHO.
Attachments:
v40-0001-test-for-MERGE-PARTITION-TRIGGER.no-cfbotapplication/octet-stream; name=v40-0001-test-for-MERGE-PARTITION-TRIGGER.no-cfbotDownload
From 65e30962d7d9adc72ded6844b418a8bed1865f1f Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 6 Jun 2025 10:15:14 +0800
Subject: [PATCH v40 1/1] test for MERGE PARTITION TRIGGER
table property: (TRIGGER) partition can differ from root partitioned table.
When using ALTER TABLE ... MERGE PARTITIONS, the new partition's properties will
not be inherited from to be merged partitions; instead, they will be directly
copied from the root partitioned table.
---
src/test/regress/expected/partition_merge.out | 47 +++++++++++++++++--
src/test/regress/sql/partition_merge.sql | 14 ++++--
2 files changed, 54 insertions(+), 7 deletions(-)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index e8428b5864c..d8ac1796fb6 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -430,16 +430,55 @@ CREATE TRIGGER salespeople_after_insert_row_trigger
ON salespeople
FOR EACH ROW
EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
--- 2 triggers should fire here (row + statement):
+CREATE TRIGGER salespeople_after_insert_row_trigger1020
+ AFTER INSERT
+ ON salespeople10_20
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople10_20');
+-- 3 triggers should fire here (row + statement):
INSERT INTO salespeople VALUES (10, 'May');
NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople10_20) called: action = INSERT, when = AFTER, level = ROW
NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
--- 1 trigger should fire here (row):
+-- 2 trigger should fire here (row):
INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople10_20) called: action = INSERT, when = AFTER, level = ROW
ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+\d+ salespeople
+ Partitioned table "partitions_merge_schema.salespeople"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | not null | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+Partition key: RANGE (salesperson_id)
+Indexes:
+ "salespeople_pkey" PRIMARY KEY, btree (salesperson_id)
+Not-null constraints:
+ "salespeople_salesperson_id_not_null" NOT NULL "salesperson_id"
+Triggers:
+ salespeople_after_insert_row_trigger AFTER INSERT ON salespeople FOR EACH ROW EXECUTE FUNCTION after_insert_row_trigger('salespeople')
+ salespeople_after_insert_statement_trigger AFTER INSERT ON salespeople FOR EACH STATEMENT EXECUTE FUNCTION after_insert_row_trigger('salespeople')
+Partitions: salespeople01_10 FOR VALUES FROM (1) TO (10),
+ salespeople10_40 FOR VALUES FROM (10) TO (40)
+
+\d+ salespeople10_40
+ Table "partitions_merge_schema.salespeople10_40"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | not null | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+Partition of: salespeople FOR VALUES FROM (10) TO (40)
+Partition constraint: ((salesperson_id IS NOT NULL) AND (salesperson_id >= 10) AND (salesperson_id < 40))
+Indexes:
+ "salespeople10_40_pkey" PRIMARY KEY, btree (salesperson_id)
+Not-null constraints:
+ "salespeople_salesperson_id_not_null" NOT NULL "salesperson_id" (inherited)
+Triggers:
+ salespeople_after_insert_row_trigger AFTER INSERT ON salespeople10_40 FOR EACH ROW EXECUTE FUNCTION after_insert_row_trigger('salespeople'), ON TABLE salespeople
+
-- 2 triggers should fire here (row + statement):
-INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (18, 'Smirnoff');
NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
-- 1 trigger should fire here (row):
@@ -456,7 +495,7 @@ SELECT * FROM salespeople10_40;
----------------+------------------
10 | May
19 | Ivanov
- 20 | Smirnoff
+ 18 | Smirnoff
30 | Ford
(4 rows)
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 861bd186b56..7637e35ee89 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -260,15 +260,23 @@ CREATE TRIGGER salespeople_after_insert_row_trigger
FOR EACH ROW
EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
--- 2 triggers should fire here (row + statement):
+CREATE TRIGGER salespeople_after_insert_row_trigger1020
+ AFTER INSERT
+ ON salespeople10_20
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople10_20');
+
+-- 3 triggers should fire here (row + statement):
INSERT INTO salespeople VALUES (10, 'May');
--- 1 trigger should fire here (row):
+-- 2 trigger should fire here (row):
INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+\d+ salespeople
+\d+ salespeople10_40
-- 2 triggers should fire here (row + statement):
-INSERT INTO salespeople VALUES (20, 'Smirnoff');
+INSERT INTO salespeople VALUES (18, 'Smirnoff');
-- 1 trigger should fire here (row):
INSERT INTO salespeople10_40 VALUES (30, 'Ford');
--
2.34.1
hi.
in createTableConstraints
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
Here, StoreConstraints last argument should be set to true?
see also StoreAttrDefault.
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of
relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
you can use TupleDescGetDefault, build_generation_expression
to simplify the above code.
The attached patch fixes the above issues.
it is based on v41-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
----------------------
Do getAttributesList need to care about pg_attribute.attidentity?
currently MERGE PARTITION seems to work fine with identity columns,
this issue i didn't dig deeper.
I am wondering right after createPartitionTable,
do we need a CommandCounterIncrement?
because later moveMergedTablesRows will use the output of createPartitionTable.
Attachments:
v41-0001-misc-fixes-in-createTableConstraints.no-cfbotapplication/octet-stream; name=v41-0001-misc-fixes-in-createTableConstraints.no-cfbotDownload
From bc971ce6a8ccf17be9dbf2caec36edf549f66b2f Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 6 Jun 2025 15:07:32 +0800
Subject: [PATCH v41 1/1] misc fixes in createTableConstraints
---
src/backend/commands/tablecmds.c | 24 ++++++++++--------------
1 file changed, 10 insertions(+), 14 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 70e76c677c8..84d961c0e2d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22169,23 +22169,19 @@ createTableConstraints(Relation modelRel, Relation newRel)
if (attribute->atthasdef)
{
Node *this_default = NULL;
- AttrDefault *attrdef = constr->defval;
bool found_whole_row;
- int16 num;
+ AttrNumber num;
Node *def;
- /* Find default in constraint structure */
- for (int i = 0; i < constr->num_defval; i++)
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
{
- if (attrdef[i].adnum == parent_attno)
- {
- this_default = stringToNode(attrdef[i].adbin);
- break;
- }
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
}
- if (this_default == NULL)
- elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
- parent_attno, RelationGetRelationName(modelRel));
num = attmap->attnums[parent_attno - 1];
def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
@@ -22195,7 +22191,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
* that defaults cannot contain any vars, so it's OK that the
* error message refers to generated columns.
*/
- if (found_whole_row)
+ if (found_whole_row && attribute->attgenerated != '\0')
ereport(ERROR,
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert whole-row table reference"),
@@ -22253,7 +22249,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
}
/* Store CHECK constraints. */
- StoreConstraints(newRel, cookedConstraints, false);
+ StoreConstraints(newRel, cookedConstraints, true);
/* Don't need the cookedConstraints any more. */
list_free_deep(cookedConstraints);
--
2.34.1
Hi, Jian He!
Thanks for the suggestions and patches!
This email contains comments to three emails (05/06/2025).
I hope to read two emails (for 06/06/2025) tomorrow.
1.
What should we do when any to be merged partition has constraints?
...
Maybe this is expected, but we need to mention it somewhere and have
some tests on it saying that MERGE PARTITIONS will effectively drop
the partitions, so if any object depends on that partition
then MERGE PARTITIONS can not be done.
Added following phrases to the documentation (I hope this should be
enough?):
If merged partitions have individual constraints, those constraints will
be dropped because command uses partitioned table as a model to create
the constraints.
If merged partitions have some objects dependent on them, the command
can not be done (CASCADE is not used, an error will be returned).
2.
... so this error check can be performed as early as the
transformPartitionCmdForMerge stage?
Function createPartitionTable will be used for various other cases
besides MERGE PARTITIONS: for SPLIT PARTITION, for PARTITION BY
REFERENCE (I hope).
So I think it's better to minimize the amount of code and not move the
same one check into different functions (transformPartitionCmdForMerge,
transformPartitionCmdForSplit, ...).
3.
i think, we can do the following way:
if (modelRel->rd_rel->relam)
elog(ERROR, "error");
relamId = modelRel->rd_rel->relam;
Can you clarify what is reason to change the current AM-logic for
creating a new partition?
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ?
modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
(If AM is set for a partitioned table, then use it, otherwise use AM for
heap tables.)
4.
Attached is some refactoring in moveMergedTablesRows, hope it's
straightforward.
Thanks, these changes are useful.
5.
bug in transformPartitionCmdForMerge "equal(name, name2))"
...
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
public.sales_feb2022) INTO sales_feb_mar2022;
ERROR: lower bound of partition "sales_feb2022" conflicts with upper
bound of previous partition "sales_feb2022"
in this context. "sales_feb2022" is the same as "public.sales_feb2022".
Added check and test for this case.
6.
When using ALTER TABLE ... MERGE PARTITIONS, some of the new
partition's properties will not be inherited from to be merged
partitions; instead, they will be directly copied from the root
partitioned table.
So we need to test this behavior.
The attached test file is for test table properties:
(COMMENTS, COMPRESSION, DEFAULTS, GENERATED, STATISTICS, STORAGE).
Some tests already exist (GENERATED, DEFAULTS) - see
partition_merge.sql, lines after:
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
...
But the complex test is probably also interesting.
Test added.
--
Similar changes are made for the second commit (SPLIT PARTITION).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v42-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v42-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From c640bf22a681c4f9c12482fd4fb8c0efcd976a8d Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v42 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 105 +-
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 651 +++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 144 +++
src/backend/partitioning/partbounds.c | 212 +++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1068 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 708 +++++++++++
19 files changed, 3189 insertions(+), 28 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..8201efac86 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,102 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the <literal>DEFAULT</literal> partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ If merged partitions have individual constraints, those constraints will
+ be dropped because command uses partitioned table as a model to create
+ the constraints.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1488,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1922,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..d6ce87dd96 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,583 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ AttrDefault *attrdef = constr->defval;
+ bool found_whole_row;
+ int16 num;
+ Node *def;
+
+ /* Find default in constraint structure */
+ for (int i = 0; i < constr->num_defval; i++)
+ {
+ if (attrdef[i].adnum == parent_attno)
+ {
+ this_default = stringToNode(attrdef[i].adbin);
+ break;
+ }
+ }
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ parent_attno, RelationGetRelationName(modelRel));
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = false;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, false);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+ AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ 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 = table_slot_create(newPartRel, NULL);
+
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ ListCell *listptr;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach(listptr, cmd->partlist)
+ {
+ RangeVar *name = (RangeVar *) lfirst(listptr);
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach(listptr, mergingPartitionsList)
+ {
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..47823ef7a5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..7815e8d245 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,134 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3896,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index dd00ab420b..1ff0e7f6f0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -959,8 +959,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..f754849039
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1068 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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"
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+CREATE TABLE t
+(i int,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..f8324f01e5
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,708 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+
+CREATE TABLE t
+(i int,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v42-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v42-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 1e2c2ee9d580a8726d2d713cfa0e9bca4a1d9ad1 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v42 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 95 +-
src/backend/commands/tablecmds.c | 416 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 59 +-
src/backend/partitioning/partbounds.c | 689 +++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1835 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1142 ++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4578 insertions(+), 19 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8201efac86..4f80813412 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,74 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ If split partition has individual constraints, those constraints will
+ be dropped because command uses partitioned table as a model to create
+ the constraints.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1245,7 +1317,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1489,7 +1562,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1922,6 +1995,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d6ce87dd96..3fe46e60e3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22073,6 +22095,254 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach(listptr, partContexts)
+ deleteSplitPartitionContext((SplitPartitionContext *) lfirst(listptr), ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22381,6 +22651,152 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach(listptr, cmd->partlist)
+ {
+ Oid existingRelid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach(listptr, cmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 47823ef7a5..750f531b81 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 7815e8d245..1b01facffd 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,40 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+ ListCell *listptr;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach(listptr, partcmd->partlist)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3888,7 +3922,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3896,6 +3930,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3904,7 +3939,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4339,13 +4378,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4354,9 +4393,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4364,7 +4403,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..42146c3bfa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,636 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+ ListCell *cell;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach(cell, spec->listdatums)
+ {
+ Const *val = lfirst_node(Const, cell);
+
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ ListCell *valptr;
+ int i;
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach(valptr, sps->bound->listdatums)
+ {
+ Const *val = lfirst_node(Const, valptr);
+
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ ListCell *listptr;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach(listptr, partlist)
+ {
+ SinglePartitionSpec *sps =
+ (SinglePartitionSpec *) lfirst(listptr);
+
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1ff0e7f6f0..bbd1110a40 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -953,15 +953,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..ac1be22a32
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1835 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+CREATE TABLE t
+(i int,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..9398e6b85d
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1142 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+
+CREATE TABLE t
+(i int,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2826,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Tue, Jun 10, 2025 at 6:48 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
3.
i think, we can do the following way:
if (modelRel->rd_rel->relam)
elog(ERROR, "error");
relamId = modelRel->rd_rel->relam;Can you clarify what is reason to change the current AM-logic for
creating a new partition?+ /* Look up the access method for new relation. */ + relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;(If AM is set for a partitioned table, then use it, otherwise use AM for
heap tables.)
I only want to allow HEAP_TABLE_AM_OID to be used
in the merge partition,
I guess that would avoid unintended consequences.
I proposed change was
+if (modelRel->rd_rel->relam != HEAP_TABLE_AM_OID)
+ elog(ERROR, "only heap table method is allowed");
+ relamId = modelRel->rd_rel->relam;
RangeVarGetAndCheckCreationNamespace
was called first on ATExecMergePartitions, then on createPartitionTable.
Maybe we can pass the first ATExecMergePartitions call result
to createPartitionTable to avoid calling it twice.
CREATE TABLE pp (a int, b int) PARTITION BY LIST(a);
CREATE TABLE pp_p1 PARTITION OF pp FOR VALUES IN (1, 2);
CREATE TABLE pp_p2 PARTITION OF pp FOR VALUES IN (3, 4);
INSERT INTO pp(a, b) SELECT random(min=>1, max=>6),
random(min=>1::int, max=>10) FROM generate_series(0, 4) i;
alter table pp add constraint cc check(a < 0) not valid;
ALTER TABLE pp MERGE PARTITIONS (pp_p1, pp_p2) INTO pp_p1_2;
src4=# \d+ pp_p1_2
Table "public.pp_p1_2"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
a | integer | | | | plain |
| |
b | integer | | | | plain |
| |
Partition of: pp FOR VALUES IN (1, 2, 3, 4)
Partition constraint: ((a IS NOT NULL) AND (a = ANY (ARRAY[1, 2, 3, 4])))
Check constraints:
"cc" CHECK (a < 0)
Access method: heap
constraint cc on pp_p1_2 should be NOT VALID.
also if the partitioned table has NOT ENFORCED CHECK constraint, it
will cause segfault.
attached is a possible fix, and related tests.(based on v42).
cosmetic changes:
many of the "forach" can change to "foreach_node".
for example in ATExecMergePartitions.
we can change
``foreach(listptr, cmd->partlist)``
to
``foreach_node(RangeVar, name, cmd->partlist)`
Attachments:
v42-0001-fix-MERGE-PARTITION-with-partitioned-table-not-enforc.no-cfbotapplication/octet-stream; name=v42-0001-fix-MERGE-PARTITION-with-partitioned-table-not-enforc.no-cfbotDownload
From fae090a20dcdc98a7d9c77ccd03e3f2185e107a6 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Tue, 10 Jun 2025 13:21:44 +0800
Subject: [PATCH v42 1/1] fix MERGE PARTITION with partitioned table not
enforced/valid constr
add tests for MERGE PARTITION while partitioned table have
* not valid not-null constraint
* not enforced check constraint
* not valid check constraint
* not enforced foreign key constraint
* not valid foreign key constraint
also changed createTableConstraints to make ALTER TABLE MERGE PARTITION support
these (not valid, not enforced) constraints.
---
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 10 ++-
src/test/regress/expected/partition_merge.out | 62 ++++++++++++++++++-
src/test/regress/sql/partition_merge.sql | 29 +++++++++
4 files changed, 98 insertions(+), 5 deletions(-)
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea813..1f948876d98 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d6ce87dd965..0375e5251f5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22215,6 +22215,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
char *ccbin = constr->check[ccnum].ccbin;
bool ccenforced = constr->check[ccnum].ccenforced;
bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
Node *ccbin_node;
bool found_whole_row;
CookedConstraint *cooked;
@@ -22245,7 +22246,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
cooked->attnum = 0;
cooked->expr = ccbin_node;
cooked->is_enforced = ccenforced;
- cooked->skip_validation = false;
+ cooked->skip_validation = !ccvalid;
cooked->is_local = true;
cooked->inhcount = 0;
cooked->is_no_inherit = ccnoinherit;
@@ -22267,7 +22268,12 @@ createTableConstraints(Relation modelRel, Relation newRel)
false, true);
Assert(list_length(nnconstraints) > 0);
- AddRelationNotNullConstraints(newRel, nnconstraints, NULL);
+
+ /*
+ * we already set pg_attribute.attnotnull in createPartitionTable. no
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
}
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index f754849039e..fb7413d9fed 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -1032,20 +1032,27 @@ CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
\d+ tp_0_1
Table "partitions_merge_schema.tp_0_1"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
i | integer | | | | plain | | tp_0_1.i
t | text | | | 'default_tp_0_1'::text | main | |
- b | bigint | | | | plain | |
+ b | bigint | | not null | | plain | |
d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
Partition of: t FOR VALUES FROM (0) TO (1)
Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
Check constraints:
"t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
Statistics objects:
"partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
\d+ tp_0_1
@@ -1054,14 +1061,65 @@ ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
i | integer | | | | plain | |
t | text | | | 'default_t'::text | extended | |
- b | bigint | | | | plain | |
+ b | bigint | | not null | | plain | |
d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
Check constraints:
"t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
DROP TABLE t;
+-- Test MERGE PARTITIONS with not valid or not enforced foreign key constraint
+CREATE TABLE pk (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE pk_1 PARTITION OF pk FOR VALUES FROM (0) TO (1);
+CREATE TABLE pk_2 PARTITION OF pk FOR VALUES FROM (1) TO (2);
+INSERT INTO pk VALUES (0), (1);
+CREATE TABLE fk (i INT);
+INSERT INTO fk VALUES (1), (2);
+ALTER TABLE fk ADD CONSTRAINT fk_i_fkey FOREIGN KEY (i) REFERENCES pk NOT VALID;
+ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk12;
+\d pk12
+ Table "partitions_merge_schema.pk12"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: pk FOR VALUES FROM (0) TO (2)
+Indexes:
+ "pk12_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "fk" CONSTRAINT "fk_i_fkey" FOREIGN KEY (i) REFERENCES pk(i) NOT VALID
+
+ALTER TABLE fk validate constraint fk_i_fkey; --error
+ERROR: insert or update on table "fk" violates foreign key constraint "fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "pk".
+DROP TABLE IF EXISTS fk, pk CASCADE;
+CREATE TABLE pk (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE pk_1 PARTITION OF pk FOR VALUES FROM (0) TO (1);
+CREATE TABLE pk_2 PARTITION OF pk FOR VALUES FROM (1) TO (2);
+INSERT INTO pk VALUES (0), (1);
+CREATE TABLE fk (i INT);
+INSERT INTO fk VALUES (1), (2);
+ALTER TABLE fk ADD CONSTRAINT fk_i_fkey FOREIGN KEY (i) REFERENCES pk NOT ENFORCED;
+ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk12;
+\d pk12
+ Table "partitions_merge_schema.pk12"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: pk FOR VALUES FROM (0) TO (2)
+Indexes:
+ "pk12_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "fk" CONSTRAINT "fk_i_fkey" FOREIGN KEY (i) REFERENCES pk(i) NOT ENFORCED
+
+ALTER TABLE fk ALTER CONSTRAINT fk_i_fkey ENFORCED; --error
+ERROR: insert or update on table "fk" violates foreign key constraint "fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "pk".
+DROP TABLE IF EXISTS fk, pk CASCADE;
RESET search_path;
--
DROP SCHEMA partitions_merge_schema;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index f8324f01e5c..df424e42d10 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -693,6 +693,9 @@ CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
\d+ tp_0_1
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
@@ -700,6 +703,32 @@ ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
DROP TABLE t;
+-- Test MERGE PARTITIONS with not valid or not enforced foreign key constraint
+CREATE TABLE pk (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE pk_1 PARTITION OF pk FOR VALUES FROM (0) TO (1);
+CREATE TABLE pk_2 PARTITION OF pk FOR VALUES FROM (1) TO (2);
+INSERT INTO pk VALUES (0), (1);
+CREATE TABLE fk (i INT);
+INSERT INTO fk VALUES (1), (2);
+ALTER TABLE fk ADD CONSTRAINT fk_i_fkey FOREIGN KEY (i) REFERENCES pk NOT VALID;
+ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk12;
+\d pk12
+ALTER TABLE fk validate constraint fk_i_fkey; --error
+
+DROP TABLE IF EXISTS fk, pk CASCADE;
+CREATE TABLE pk (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE pk_1 PARTITION OF pk FOR VALUES FROM (0) TO (1);
+CREATE TABLE pk_2 PARTITION OF pk FOR VALUES FROM (1) TO (2);
+INSERT INTO pk VALUES (0), (1);
+CREATE TABLE fk (i INT);
+INSERT INTO fk VALUES (1), (2);
+
+ALTER TABLE fk ADD CONSTRAINT fk_i_fkey FOREIGN KEY (i) REFERENCES pk NOT ENFORCED;
+ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk12;
+\d pk12
+
+ALTER TABLE fk ALTER CONSTRAINT fk_i_fkey ENFORCED; --error
+DROP TABLE IF EXISTS fk, pk CASCADE;
RESET search_path;
--
2.34.1
Hi Dmitry,
On Tue, Jun 10, 2025 at 6:48 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi, Jian He!
Thanks for the suggestions and patches!
This email contains comments to three emails (05/06/2025).
I hope to read two emails (for 06/06/2025) tomorrow.1.
What should we do when any to be merged partition has constraints?
...
Maybe this is expected, but we need to mention it somewhere and have
some tests on it saying that MERGE PARTITIONS will effectively drop
the partitions, so if any object depends on that partition
then MERGE PARTITIONS can not be done.Added following phrases to the documentation (I hope this should be
enough?):If merged partitions have individual constraints, those constraints will
be dropped because command uses partitioned table as a model to create
the constraints.
If merged partitions have some objects dependent on them, the command
can not be done (CASCADE is not used, an error will be returned).2.
... so this error check can be performed as early as the
transformPartitionCmdForMerge stage?Function createPartitionTable will be used for various other cases
besides MERGE PARTITIONS: for SPLIT PARTITION, for PARTITION BY
REFERENCE (I hope).
So I think it's better to minimize the amount of code and not move the
same one check into different functions (transformPartitionCmdForMerge,
transformPartitionCmdForSplit, ...).3.
i think, we can do the following way:
if (modelRel->rd_rel->relam)
elog(ERROR, "error");
relamId = modelRel->rd_rel->relam;Can you clarify what is reason to change the current AM-logic for
creating a new partition?+ /* Look up the access method for new relation. */ + relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;(If AM is set for a partitioned table, then use it, otherwise use AM for
heap tables.)4.
Attached is some refactoring in moveMergedTablesRows, hope it's
straightforward.
Thanks, these changes are useful.
5.
bug in transformPartitionCmdForMerge "equal(name, name2))"
...
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
public.sales_feb2022) INTO sales_feb_mar2022;
ERROR: lower bound of partition "sales_feb2022" conflicts with upper
bound of previous partition "sales_feb2022"
in this context. "sales_feb2022" is the same as "public.sales_feb2022".Added check and test for this case.
6.
When using ALTER TABLE ... MERGE PARTITIONS, some of the new
partition's properties will not be inherited from to be merged
partitions; instead, they will be directly copied from the root
partitioned table.
So we need to test this behavior.
The attached test file is for test table properties:
(COMMENTS, COMPRESSION, DEFAULTS, GENERATED, STATISTICS, STORAGE).Some tests already exist (GENERATED, DEFAULTS) - see
partition_merge.sql, lines after:+-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. ...But the complex test is probably also interesting.
Test added.--
Similar changes are made for the second commit (SPLIT PARTITION).
--
With best regards,
Dmitry KovalPostgres Professional: http://postgrespro.com
I had one trivial comment and a question if you don't mind.
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another
session"));
Would it be better to use RELATION_IS_OTHER_TEMP in this case?
I noticed that while other parts of tablecmds.c don’t use the macro,
all other files consistently use RELATION_IS_OTHER_TEMP.
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
I have trouble understanding how this is possible, can you kindly
give me some guidance on this logic?
--
Regards
Junwang Zhao
Hi!
This email contains comments to three emails
(2 x 06.06.2025 + 1 x 10.06.2025).
1.
I am surprised that partition_merge.sql doesn't have much \d+ command.
so I added two, which is necessary IMHO.
I think that a lot of \d+ commands can make the out-files difficult to
read. But I agree, that test for triggers is useful. Test for triggers
added to test of partition properties.
2.
Here, StoreConstraints last argument should be set to true?
see also StoreAttrDefault.
Thanks, this is correct.
you can use TupleDescGetDefault, build_generation_expression
to simplify the above code.
Should we use ATTRIBUTE_GENERATED_VIRTUAL [1]Virtual generated columns, https://github.com/postgres/postgres/commit/83ea6c54025bea67bcd4949a6d58d3fc11c3e21b and
build_generation_expression [2]Expand virtual generated columns in the planner, https://github.com/postgres/postgres/commit/1e4351af329f2949c679a215f63c51d663ecd715 here? Function expandTableLikeClause
("CREATE TABLE ... LIKE ..." clause) does not use GENERATED VIRTUAL
yet ...
Do getAttributesList need to care about pg_attribute.attidentity?
currently MERGE PARTITION seems to work fine with identity columns,
this issue i didn't dig deeper.
Probably after commit [3]Support identity columns in partitioned tables, https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49 partition's identity columns shares the
identity space (i.e. underlying sequence) as the corresponding
columns of the partitioned table. So call BuildDescForRelation in
createPartitionTable function should copy pg_attribute.attidentity
for new partition.
I am wondering right after createPartitionTable,
do we need a CommandCounterIncrement?
because later moveMergedTablesRows will use the output of
createPartitionTable.
We call CommandCounterIncrement in createPartitionTable function right
after heap_create_with_catalog (same code in create_toast_table,
make_new_heap, DefineRelation functions). We need an additional
CommandCounterIncrement call in case we use objects created after this
point. But we probably don't use these objects (in function
moveMergedTablesRows too).
3.
I only want to allow HEAP_TABLE_AM_OID to be used
in the merge partition,
I guess that would avoid unintended consequences.
Thanks for the clarification. Isn't this limitation too strong?
It is very likely that the user will create an AM based on
HEAP_TABLE_AM_OID, in which case the code should work.
RangeVarGetAndCheckCreationNamespace
was called first on ATExecMergePartitions, then on
createPartitionTable. Maybe we can pass the first
ATExecMergePartitions call result to createPartitionTable to avoid
calling it twice.
Unfortunately, this is not the case for SPLIT PARTITION. I will think
about it, but I am concerned that the createPartitionTable function
will be passed two related arguments - newPartName and namespaceId
(result of RangeVarGetAndCheckCreationNamespace).
Thanks for
v42-0001-fix-MERGE-PARTITION-with-partitioned-table-not-enforc.no-cfbot!
I forgot about not valid or not enforced constraints.
cosmetic changes:
many of the "forach" can change to "foreach_node".
for example in ATExecMergePartitions.
we can change
``foreach(listptr, cmd->partlist)``
to
``foreach_node(RangeVar, name, cmd->partlist)`
Changed.
Links.
------
[1]: Virtual generated columns, https://github.com/postgres/postgres/commit/83ea6c54025bea67bcd4949a6d58d3fc11c3e21b
https://github.com/postgres/postgres/commit/83ea6c54025bea67bcd4949a6d58d3fc11c3e21b
[2]: Expand virtual generated columns in the planner, https://github.com/postgres/postgres/commit/1e4351af329f2949c679a215f63c51d663ecd715
https://github.com/postgres/postgres/commit/1e4351af329f2949c679a215f63c51d663ecd715
[3]: Support identity columns in partitioned tables, https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49
https://github.com/postgres/postgres/commit/699586315704a8268808e3bdba4cb5924a038c49
P.S. 2Junwang Zhao: sorry, I'll write an answer a little later.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v43-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v43-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From cd67f4df61a084d077f6ee95207271dbc3124733 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v43 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 105 +-
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 646 ++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 144 ++
src/backend/partitioning/partbounds.c | 212 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1155 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 766 +++++++++++
20 files changed, 3330 insertions(+), 29 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index fcd1cb8535..199d57f4c7 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4439,6 +4439,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..8201efac86 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,102 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the <literal>DEFAULT</literal> partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ If merged partitions have individual constraints, those constraints will
+ be dropped because command uses partitioned table as a model to create
+ the constraints.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1488,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1922,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..92bed4a2dd 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,578 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ */
+static void
+createTableConstraints(Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = !ccvalid;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, true);
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
+ !modelRel->rd_islocaltemp)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(modelRel, newRel);
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel).
+ */
+static void
+moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
+ Relation newPartRel)
+{
+ CommandId mycid;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ 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 = table_slot_create(newPartRel, NULL);
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ 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 <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(mergingPartition, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ ObjectAddress object;
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..47823ef7a5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2332,6 +2332,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2346,6 +2347,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2359,6 +2361,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2375,6 +2392,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17909,6 +17927,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18536,6 +18555,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..7815e8d245 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,134 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3896,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec65ab79fe..4bf1560c89 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index dd00ab420b..1ff0e7f6f0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -959,8 +959,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..e76cea2a03
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1155 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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"
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..d72af062ee
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,766 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v43-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v43-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 680b96df014a7323ba2bf22b3c0875e300fedd68 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v43 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 95 +-
src/backend/commands/tablecmds.c | 414 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 56 +-
src/backend/partitioning/partbounds.c | 677 ++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1866 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1160 ++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4610 insertions(+), 19 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 199d57f4c7..27943b5fff 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4460,6 +4460,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8201efac86..4f80813412 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,74 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ If split partition has individual constraints, those constraints will
+ be dropped because command uses partitioned table as a model to create
+ the constraints.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1245,7 +1317,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1489,7 +1562,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1922,6 +1995,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 92bed4a2dd..922abf7284 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,9 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
@@ -4836,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
case AT_MergePartitions:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5275,6 +5282,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_MergePartitions:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
@@ -5676,6 +5688,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
case AT_DetachPartitionFinalize:
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
case AT_MergePartitions:
cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
cur_pass, context);
@@ -6724,6 +6744,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION";
case AT_DetachPartitionFinalize:
return "DETACH PARTITION ... FINALIZE";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_MergePartitions:
return "MERGE PARTITIONS";
case AT_AddIdentity:
@@ -22073,6 +22095,254 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, int ti_options)
+{
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+
/*
* getAttributesList: return list of columns (ColumnDef) like model table
* (modelRel)
@@ -22383,6 +22653,150 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
return newRel;
}
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ RemoveInheritance(splitRel, rel, false);
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, splitRel, false, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
+
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 47823ef7a5..750f531b81 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2322,6 +2325,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2366,6 +2386,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17996,6 +18030,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18636,6 +18671,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 7815e8d245..7e1f64cf50 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,37 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3888,7 +3919,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3896,6 +3927,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3904,7 +3936,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4339,13 +4375,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4354,9 +4390,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4364,7 +4400,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..026c2b80b3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,624 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 4bf1560c89..20ac6995d3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1ff0e7f6f0..bbd1110a40 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -953,15 +953,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..df1c29b419
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1866 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..7664937692
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1160 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2826,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
we generally no need to worry about the partitioned table check constraint,
generated column does not apply to newly merged partitions.
since partitioned table constraints apply to each individual partition,
including newly created partitions.
However, there are corner cases:
constraints include tableoid column reference.
say pk_1, pk_2 is the partition of pk.
alter table pk add constraint cc check(tableoid <> 18259);
Here, Constraint cc will check whether the tableoid of pk_1 or pk_2 meets the
specified criteria. Similarly, if partitions are merged, the newly merged
partition must also be evaluated against the constraint cc to ensure
it is satisfied.
----------------
The attached patch ensures that the newly merged partition is evaluated against
all of its check constraints and that all stored generated columns are
recomputed, i guess this would be more safe.
Alternatively, we can use pull_varattnos to check whether a constraint or
generated expression contains a reference to the tableoid column.
Attachments:
v43-0001-MERGE-PARTITIONS-constraint-revalidation.no-cfbotapplication/octet-stream; name=v43-0001-MERGE-PARTITIONS-constraint-revalidation.no-cfbotDownload
From 2892e780adc08ed63c1a6e99855f5689a5c5b74c Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 11 Jun 2025 11:59:41 +0800
Subject: [PATCH v43 1/1] MERGE PARTITIONS constraint revalidation.
ALTER TABLE MERGE PARTITIONS, partitioned table check constraints and generated
columns can sometimes reference the tableoid column. Because of this, ALTER
TABLE MERGE PARTITIONS must re-validate these constraints. To ensure data
integrity, it might be safest to unconditionally recompute all generated
expressions and re-evaluate all the check constraints again.
---
src/backend/commands/tablecmds.c | 178 +++++++++++++++++-
src/test/regress/expected/partition_merge.out | 12 ++
src/test/regress/sql/partition_merge.sql | 4 +
3 files changed, 186 insertions(+), 8 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 92bed4a2dd7..07a3742d25d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22129,15 +22129,18 @@ getAttributesList(Relation modelRel)
/*
* createTableConstraints: create constraints, default values and generated
* values (prototype is function expandTableLikeClause).
+ * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
*/
static void
-createTableConstraints(Relation modelRel, Relation newRel)
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation modelRel, Relation newRel)
{
TupleDesc tupleDesc;
TupleConstr *constr;
AttrMap *attmap;
AttrNumber parent_attno;
int ccnum;
+ ListCell *lcon;
List *cookedConstraints = NIL;
tupleDesc = RelationGetDescr(modelRel);
@@ -22172,6 +22175,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
bool found_whole_row;
AttrNumber num;
Node *def;
+ NewColumnValue *newval;
if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
this_default = build_generation_expression(modelRel, attribute->attnum);
@@ -22201,6 +22205,21 @@ createTableConstraints(Relation modelRel, Relation newRel)
/* Add a pre-cooked default expression. */
StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in modelRel might reference
+ * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within moveMergedTablesRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
}
}
@@ -22252,6 +22271,29 @@ createTableConstraints(Relation modelRel, Relation newRel)
/* Store CHECK constraints. */
StoreConstraints(newRel, cookedConstraints, true);
+ /*
+ * modelRel check constraint expresssion may reference tableoid, so later in
+ * moveMergedTablesRows, we need evulate the check constraint again for the
+ * newRel. We can check weather check constraint contain tableoid reference
+ * or not via pull_varattnos. But unconditionaly revaulate check cosntraint
+ * seems more safe.
+ */
+ foreach(lcon, cookedConstraints)
+ {
+ CookedConstraint *ccon = (CookedConstraint *) lfirst(lcon);
+
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ NewConstraint *newcon;
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = ccon->expr;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+
/* Don't need the cookedConstraints any more. */
list_free_deep(cookedConstraints);
@@ -22287,7 +22329,8 @@ createTableConstraints(Relation modelRel, Relation newRel)
* Function returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
-createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation modelRel, Oid ownerId)
{
Relation newRel;
Oid newRelId;
@@ -22296,6 +22339,7 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
List *colList = NIL;
Oid relamId;
Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
/* If existing rel is temp, it must belong to this session */
if (modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
@@ -22356,6 +22400,9 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
*/
newRel = table_open(newRelId, NoLock);
+ /* Find or create work queue entry for newly created table */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
/*
* We intended to create the partition with the same persistence as the
* parent table, but we still need to recheck because that might be
@@ -22378,7 +22425,12 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
RelationGetRelationName(modelRel)));
/* Create constraints, default values and generated values */
- createTableConstraints(modelRel, newRel);
+ createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+
+ /*
+ * need CCI, so fresh relcache entry have newly installed constraint info.
+ */
+ CommandCounterIncrement();
return newRel;
}
@@ -22386,19 +22438,64 @@ createPartitionTable(RangeVar *newPartName, Relation modelRel, Oid ownerId)
/*
* moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
* of the partitioned table (rel) and move rows into the new partition
- * (newPartRel).
+ * (newPartRel). We also reevaulate check constraints against these rows.
*/
static void
-moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
- Relation newPartRel)
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitionsList, Relation newPartRel)
{
CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *l;
+ ListCell *ltab;
/* The FSM is empty, so don't bother using it. */
int ti_options = TABLE_INSERT_SKIP_FSM;
BulkInsertState bistate; /* state of bulk inserts for partition */
TupleTableSlot *dstslot;
+ /* Find the work queue entry for new partition table: newPartRel */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /*
+ * Generate the constraint and default execution states
+ */
+ estate = CreateExecutorState();
+
+ /* Build the needed expression execution states */
+ foreach(l, tab->constraints)
+ {
+ NewConstraint *con = lfirst(l);
+
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach(l, tab->newvals)
+ {
+ NewColumnValue *ex = lfirst(l);
+
+ /* expr already planned */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
mycid = GetCurrentCommandId(true);
/* Prepare a BulkInsertState for table_tuple_insert. */
@@ -22456,9 +22553,62 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
ExecStoreVirtualTuple(insertslot);
}
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ econtext->ecxt_scantuple = insertslot;
+ foreach(l, tab->newvals)
+ {
+ NewColumnValue *ex = lfirst(l);
+
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach(l, tab->constraints)
+ {
+ NewConstraint *con = lfirst(l);
+
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
/* Write the tuple out to the new relation. */
table_tuple_insert(newPartRel, insertslot, mycid,
ti_options, bistate);
+
+ ResetExprContext(econtext);
}
table_endscan(scan);
@@ -22470,10 +22620,22 @@ moveMergedTablesRows(Relation rel, List *mergingPartitionsList,
ExecDropSingleTupleTableSlot(srcslot);
}
+ FreeExecutorState(estate);
ExecDropSingleTupleTableSlot(dstslot);
FreeBulkInsertState(bistate);
table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * in Phase3, we don't need process this newPartRel. since we already
+ * processed in here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
}
/*
@@ -22597,7 +22759,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Create table for new partition, use partitioned table as model. */
Assert(OidIsValid(ownerId));
- newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
/*
* Switch to the table owner's userid, so that any index functions are run
@@ -22613,7 +22775,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RestrictSearchPath();
/* Copy data from merged partitions to new partition. */
- moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+ moveMergedTablesRows(wqueue, rel, mergingPartitionsList, newPartRel);
/* Drop the current partitions before attaching the new one. */
foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index e76cea2a03b..064206b9737 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -1036,6 +1036,8 @@ ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
$BODY$
BEGIN
@@ -1093,6 +1095,16 @@ Not-null constraints:
Triggers:
t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
DROP TABLE t;
DROP FUNCTION trigger_function();
-- Test MERGE PARTITIONS with not valid foreign key constraint
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index d72af062eee..a832eb855ed 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -698,6 +698,8 @@ ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
$BODY$
BEGIN
@@ -717,6 +719,8 @@ CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
\d+ tp_0_1
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
DROP TABLE t;
DROP FUNCTION trigger_function();
--
2.34.1
On Wed, Jun 11, 2025 at 8:06 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Do getAttributesList need to care about pg_attribute.attidentity?
currently MERGE PARTITION seems to work fine with identity columns,
this issue i didn't dig deeper.Probably after commit [3] partition's identity columns shares the
identity space (i.e. underlying sequence) as the corresponding
columns of the partitioned table. So call BuildDescForRelation in
createPartitionTable function should copy pg_attribute.attidentity
for new partition.
but BuildDescForRelation is based on getAttributesList,
in getAttributesList, assign pg_attribute.attidentity to def->identity
should be safe, IMHO.
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new
partition.
+ </para>
+ <para>
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
since they <para> are related, these two can be one <para>?
+ <para>
+ If merged partitions have individual constraints, those constraints will
+ be dropped because command uses partitioned table as a model to create
+ the constraints.
+ </para>
I feel like it's not fully accurate, the following is what I can come up with:
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because ALTER TABLE MERGE PARTITIONS uses the partitioned table itself as the
+ template to define these objects.
+ </para>
I am wondering right after createPartitionTable,
do we need a CommandCounterIncrement?
because later moveMergedTablesRows will use the output of
createPartitionTable.We call CommandCounterIncrement in createPartitionTable function right
after heap_create_with_catalog (same code in create_toast_table,
make_new_heap, DefineRelation functions). We need an additional
CommandCounterIncrement call in case we use objects created after this
point. But we probably don't use these objects (in function
moveMergedTablesRows too).
As mentioned in the previous thread [1]/messages/by-id/CACJufxH3mfNYfHy9+dCUZPhOsmVRtJUJbWU1vH248Lg0eZjhzQ@mail.gmail.com, moveMergedTablesRows need
latest relcache entry for newPartRel. so I guess, put one
CommandCounterIncrement at the end of createPartitionTable
should be fine, which I already did in [1]/messages/by-id/CACJufxH3mfNYfHy9+dCUZPhOsmVRtJUJbWU1vH248Lg0eZjhzQ@mail.gmail.com.
[1]: /messages/by-id/CACJufxH3mfNYfHy9+dCUZPhOsmVRtJUJbWU1vH248Lg0eZjhzQ@mail.gmail.com
3.
I only want to allow HEAP_TABLE_AM_OID to be used
in the merge partition,
I guess that would avoid unintended consequences.Thanks for the clarification. Isn't this limitation too strong?
It is very likely that the user will create an AM based on
HEAP_TABLE_AM_OID, in which case the code should work.
ok.
if you looking at ATExecDetachPartition, we have:
/*
* Detaching the partition might involve TOAST table access, so ensure we
* have a valid snapshot.
*/
PushActiveSnapshot(GetTransactionSnapshot());
/* Do the final part of detaching */
DetachPartitionFinalize(rel, partRel, concurrent, defaultPartOid);
PopActiveSnapshot();
do we need do the same to the following DetachPartitionFinalize:
foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
{
/* Remove the pg_inherits row first. */
RemoveInheritance(mergingPartition, rel, false);
/* Do the final part of detaching. */
DetachPartitionFinalize(rel, mergingPartition, false, defaultPartOid);
}
Hi, Junwang Zhao!
Thank you for note.
1.
Would it be better to use RELATION_IS_OTHER_TEMP in this case?
I noticed that while other parts of tablecmds.c don’t use the macro,
all other files consistently use RELATION_IS_OTHER_TEMP.
Agreed, RELATION_IS_OTHER_TEMP is better. Changed.
The fix will be in the next patch.
2.
+/* +* We intended to create the partition with the same persistence as the +* parent table, but we still need to recheck because that might be +* affected by the search_path. If the parent is permanent, so must be +* all of its partitions. +*/
I have trouble understanding how this is possible, can you kindly
give me some guidance on this logic?
Perhaps this is best explained with an example.
(see src/test/regress/sql/partition_merge.sql).
(a) Create permanent table "t":
SET search_path = partitions_merge_schema, pg_temp, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
(b) Attempt to merge persistent partitions tp_0_1, tp_1_2 into
temporary partition tp_0_2:
SET search_path = pg_temp, partitions_merge_schema, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
(c) "ALTER TABLE ... MERGE PARTITIONS ..." will return an error:
ERROR: cannot create a temporary relation as partition of permanent
relation "t"
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
hi.
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ ObjectAddress object;
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
In here, should performDeletion last flags have PERFORM_DELETION_INTERNAL?
also this is not ideal, imagine you first did all the main work in
moveMergedTablesRows,
then suddenly error out, saying:
ERROR: cannot drop table public.pk_1 because other objects depend on it
DETAIL: view public.v1 depends on table public.pk_1
HINT: Use DROP ... CASCADE to drop the dependent objects too.
(this errhint, seems not ideal in this context)
We can perform a preliminary check to determine whether dropping a partition is
allowed, and raise an error if it's not. To do it, I invented a new
function, performDeletionCheck to verify whether an object can be
safely dropped.
please check attached, it was based on v43.
Attachments:
v43-0001-check-if-we-can-drop-merging-partition-before-actuall.no-cfbotapplication/octet-stream; name=v43-0001-check-if-we-can-drop-merging-partition-before-actuall.no-cfbotDownload
From 96d2e0de87ee03a37aa0532484c75a370802bbe3 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 11 Jun 2025 21:11:55 +0800
Subject: [PATCH v43 1/1] check if we can drop merging partition before
actually did it.
---
src/backend/catalog/dependency.c | 51 ++++++++++++++++++++++++++++++++
src/backend/commands/tablecmds.c | 21 +++++++++++++
src/include/catalog/dependency.h | 2 ++
3 files changed, 74 insertions(+)
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968b..add706b9f85 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,57 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d6ce87dd965..552db167854 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22603,6 +22603,27 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
Assert(OidIsValid(ownerId));
newPartRel = createPartitionTable(cmd->name, rel, ownerId);
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ foreach(listptr, mergingPartitionsList)
+ {
+ ObjectAddress object;
+ Relation mergingPartition = (Relation) lfirst(listptr);
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
/*
* Switch to the table owner's userid, so that any index functions are run
* as that user. Also lock down security-restricted operations and
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf5243..f54233499bf 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
--
2.34.1
hi.
+/*
+ * 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().
check_partitions_for_split does not exist in v43-0001.
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
the third argument, is_internal should set to true?
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
a partitioned table can not have NO INHERIT check constraint,
you may see StoreRelCheck.
we can add an Assert: Assert(!ccnoinherit);
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
as mentioned in above, partitioned table cannot have NO INHERIT constraint,
maybe we should set RelationGetNotNullConstraints last argument to false
/*
* 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)
if we are within calculate_partition_bound_for_merge,
then we at least hold AccessShareLock for all the partOids
(see transformPartitionCmdForMerge)
partNames is a list of RangeVar one to one corresponding to partOids,
then we really do not need partNames at all for error messages handling, we can
just use get_rel_name.
so we don't need to pass partNames to calculate_partition_bound_for_merge
The attached patch is a rewrite for
calculate_partition_bound_for_merge and callees.
please let me know whether this improves code readability
in RelationBuildPartitionDesc
we have the following code pattern:
foreach(cell, inhoids)
{
Oid inhrelid = lfirst_oid(cell);
HeapTuple tuple;
PartitionBoundSpec *boundspec = NULL;
/* Try fetching the tuple from the catcache, for speed. */
tuple = SearchSysCache1(RELOID, ObjectIdGetDatum(inhrelid));
if (HeapTupleIsValid(tuple))
{
datum = SysCacheGetAttr(RELOID, tuple,
Anum_pg_class_relpartbound,
&isnull);
if (!isnull)
boundspec = stringToNode(TextDatumGetCString(datum));
ReleaseSysCache(tuple);
}
if (boundspec == NULL)
{
pg_class = table_open(RelationRelationId, AccessShareLock);
ScanKeyInit(&key[0],
Anum_pg_class_oid,
BTEqualStrategyNumber, F_OIDEQ,
ObjectIdGetDatum(inhrelid));
scan = systable_beginscan(pg_class, ClassOidIndexId, true,
NULL, 1, key);
....
}
I wonder if we should do the same in get_partition_bound_spec?
you may also see comments in RelationBuildPartitionDesc, partdesc.c line 203.
Attachments:
v43-0001-refactor-calculate_partition_bound_for_merge.no-cfbotapplication/octet-stream; name=v43-0001-refactor-calculate_partition_bound_for_merge.no-cfbotDownload
From 98efd403ffb4f5f949579855529942463afcb845 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Thu, 12 Jun 2025 15:28:05 +0800
Subject: [PATCH v43 1/1] refactor calculate_partition_bound_for_merge
---
src/backend/commands/tablecmds.c | 3 +-
src/backend/parser/parse_utilcmd.c | 5 ++-
src/backend/partitioning/partbounds.c | 53 +++++++++++----------------
src/include/partitioning/partbounds.h | 1 -
4 files changed, 27 insertions(+), 35 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 92bed4a2dd7..213bf4f0516 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22216,6 +22216,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
bool found_whole_row;
CookedConstraint *cooked;
+ Assert(!ccnoinherit);
ccbin_node = map_variable_attnos(stringToNode(ccbin),
1, 0,
attmap,
@@ -22261,7 +22262,7 @@ createTableConstraints(Relation modelRel, Relation newRel)
List *nnconstraints;
nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
- false, true);
+ false, false);
Assert(list_length(nnconstraints) > 0);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 7815e8d2455..e8040a1fb58 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3614,8 +3614,9 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
partcmd->bound->location = -1;
partcmd->bound->is_default = isDefaultPart;
if (!isDefaultPart)
- calculate_partition_bound_for_merge(parent, partcmd->partlist,
- partOids, partcmd->bound,
+ calculate_partition_bound_for_merge(parent,
+ partOids,
+ partcmd->bound,
cxt->pstate);
}
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff57..26982f13a89 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4994,18 +4994,18 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* DEFAULT partition.
*
* parent: partitioned table
- * first_name: name of first partition
+ * first_name: Oid of first partition
* first_bound: bound of first partition
- * second_name: name of second partition
+ * second_name: Oid of second partition
* second_bound: bound of second partition
* defaultPart: true if one of split partitions is DEFAULT
* pstate: pointer to ParseState struct for determining error position
*/
static void
check_two_partitions_bounds_range(Relation parent,
- RangeVar *first_name,
+ Oid first_name,
PartitionBoundSpec *first_bound,
- RangeVar *second_name,
+ Oid second_name,
PartitionBoundSpec *second_bound,
bool defaultPart,
ParseState *pstate)
@@ -5034,20 +5034,20 @@ check_two_partitions_bounds_range(Relation parent,
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)));
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ get_rel_name(second_name), get_rel_name(first_name)),
+ parser_errposition(pstate, datum->location));
}
}
/*
* get_partition_bound_spec
*
- * Returns description of partition with Oid "partOid" and name "name".
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid
*/
static PartitionBoundSpec *
-get_partition_bound_spec(Oid partOid, RangeVar *name)
+get_partition_bound_spec(Oid partOid)
{
HeapTuple tuple;
Datum datum;
@@ -5057,21 +5057,20 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
/* 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);
+ elog(ERROR, "cache lookup failed for relation %u", partOid);
datum = SysCacheGetAttr(RELOID, tuple,
Anum_pg_class_relpartbound,
&isnull);
if (isnull)
- elog(ERROR, "partition bound for relation \"%s\" is null",
- name->relname);
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
boundspec = stringToNode(TextDatumGetCString(datum));
if (!IsA(boundspec, PartitionBoundSpec))
- elog(ERROR, "expected PartitionBoundSpec for relation \"%s\"",
- name->relname);
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
ReleaseSysCache(tuple);
return boundspec;
@@ -5084,14 +5083,12 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
* 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)
@@ -5117,10 +5114,10 @@ calculate_partition_bound_for_merge(Relation parent,
* Create array of lower bounds and list of
* PartitionBoundSpec.
*/
- for (i = 0; i < nparts; i++)
+ foreach_oid(partoid, partOids)
{
- bound = get_partition_bound_spec(list_nth_oid(partOids, i),
- (RangeVar *) list_nth(partNames, i));
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true);
bounds = lappend(bounds, bound);
@@ -5137,9 +5134,9 @@ calculate_partition_bound_for_merge(Relation parent,
int prev_index = lower_bounds[i - 1]->index;
check_two_partitions_bounds_range(parent,
- (RangeVar *) list_nth(partNames, prev_index),
+ list_nth_oid(partOids, prev_index),
(PartitionBoundSpec *) list_nth(bounds, prev_index),
- (RangeVar *) list_nth(partNames, index),
+ list_nth_oid(partOids, index),
(PartitionBoundSpec *) list_nth(bounds, index),
false, pstate);
}
@@ -5165,16 +5162,10 @@ calculate_partition_bound_for_merge(Relation parent,
case PARTITION_STRATEGY_LIST:
{
- ListCell *listptr,
- *listptr2;
-
/* Consolidate bounds for all partitions in the list. */
- forboth(listptr, partOids, listptr2, partNames)
+ foreach_oid(partoid, partOids)
{
- RangeVar *name = (RangeVar *) lfirst(listptr2);
- Oid curOid = lfirst_oid(listptr);
-
- bound = get_partition_bound_spec(curOid, name);
+ bound = get_partition_bound_spec(partoid);
spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
}
break;
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d2596190..a432c2d27ff 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -144,7 +144,6 @@ 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);
--
2.34.1
hi.
one more minor issue.
+ * defaultPart: true if one of split partitions is DEFAULT
+ * pstate: pointer to ParseState struct for determining 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)
v43-0001 doesn't have the SPLIT PARTITION feature.
maybe we need to remove the argument (bool defaultPart)
from check_two_partitions_bounds_range, aslo remove the comments.
then we can add it on 0002 SPLIT PARTITION patch.
Hi, Jian He!
Thanks for the notes and patches (again).
I read a part of emails, I hope to read the rest emails tomorrow.
1.
The attached patch ensures that the newly merged partition is
evaluated against all of its check constraints and that all stored
generated columns are recomputed, i guess this would be more safe.
v43-0001-MERGE-PARTITIONS-constraint-revalidation.no-cfbot
I modified the patch to apply it to the SPLIT PARTITION command too.
2.
but BuildDescForRelation is based on getAttributesList,
in getAttributesList, assign pg_attribute.attidentity to def->identity
should be safe, IMHO.
You are right. Corrected.
3.
+<para>
+If merged partitions have different owners, an error will be generated
since they <para> are related, these two can be one <para>?
Changed.
4.
I feel like it's not fully accurate, the following is what I can come up with: +<para> + When partitions are merged, any individual objects belonging to
Changed.
5.
/*
* Detaching the partition might involve TOAST table access, so ensure
* we have a valid snapshot.
*/
PushActiveSnapshot(GetTransactionSnapshot());
/* Do the final part of detaching */
DetachPartitionFinalize(rel, partRel, concurrent, defaultPartOid);
PopActiveSnapshot();
do we need do the same to the following DetachPartitionFinalize:
...
Thanks. This needs to be done, especially after the recent commit [1]Ensure we have a snapshot when updating various system catalogs, https://github.com/postgres/postgres/commit/706054b11b959c865c0c7935c34d92370d7168d4.
Fixed.
Links.
------
[1]: Ensure we have a snapshot when updating various system catalogs, https://github.com/postgres/postgres/commit/706054b11b959c865c0c7935c34d92370d7168d4
https://github.com/postgres/postgres/commit/706054b11b959c865c0c7935c34d92370d7168d4
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v44-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v44-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 56af1c9d9ebb5f5bf729ab0969d0e3fce9c71f7d Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v44 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 104 +-
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 848 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 144 ++
src/backend/partitioning/partbounds.c | 212 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1167 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 770 +++++++++++
20 files changed, 3547 insertions(+), 29 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..855d2ca44d 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions into the one partition of the target table.
+ Hash-partitioning is not supported. If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] can
+ be merged into one range without spaces and overlaps (otherwise an error
+ will be generated). The combined range will be the range for the partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables the value lists of all partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...] are
+ combined and form the list of values of partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the <literal>DEFAULT</literal> partition.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1487,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1921,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..190ce952ad 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,780 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ ListCell *lcon;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in modelRel might reference
+ * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within moveMergedTablesRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = !ccvalid;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, true);
+
+ /*
+ * modelRel check constraint expresssion may reference tableoid, so later in
+ * moveMergedTablesRows, we need evulate the check constraint again for the
+ * newRel. We can check weather check constraint contain tableoid reference
+ * or not via pull_varattnos. But unconditionaly revaulate check cosntraint
+ * seems more safe.
+ */
+ foreach(lcon, cookedConstraints)
+ {
+ CookedConstraint *ccon = (CookedConstraint *) lfirst(lcon);
+
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ NewConstraint *newcon;
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = ccon->expr;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, true);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(modelRel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitionsList, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "partRel" from partitioned table
+ * "rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation partRel, Relation rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(partRel, rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(rel, partRel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ /* Detach all merged partitions. */
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ detachPartitionTable(mergingPartition, rel, defaultPartOid);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(wqueue, rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ ObjectAddress object;
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..7815e8d245 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,134 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3896,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 contain 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 4bdc2941ef..cb719f1ff5 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,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 equal except when
+ * "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 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 determining 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 of
+ * 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 the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2c0b4f28c1..64248b5b1f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..064206b973
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1167 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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"
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..a832eb855e
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,770 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v44-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v44-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From a31e45df8192e8b12d7c53119fa3f1afc771a678 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v44 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 94 +-
src/backend/commands/tablecmds.c | 450 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 56 +-
src/backend/partitioning/partbounds.c | 677 ++++++
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 5 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1878 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1165 ++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4662 insertions(+), 19 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 855d2ca44d..fc7ba5e63c 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,73 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table. Hash-partitioning
+ is not supported. Bounds of new partitions should not overlap with new and
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will have the same table access method as the parent.
+ If the parent table is persistent then new partitions are created
+ persistent. If the parent table is temporary then new partitions
+ are also created temporary. New partitions will also be created in
+ the same tablespace as the parent.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1244,7 +1315,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1488,7 +1560,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1921,6 +1993,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 190ce952ad..f0cb66b63a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22849,3 +22871,431 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(List **wqueue, Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(splitRel, rel, defaultPartOid);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, false, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 7815e8d245..7e1f64cf50 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,37 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->name, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3888,7 +3919,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3896,6 +3927,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3904,7 +3936,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4339,13 +4375,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4354,9 +4390,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4364,7 +4400,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index cb719f1ff5..026c2b80b3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5041,10 +5041,69 @@ check_two_partitions_bounds_range(Relation parent,
}
}
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
/*
* get_partition_bound_spec
*
* Returns description of partition with Oid "partOid" and name "name".
+ *
+ * partOid: partition Oid
+ * name: partition name
*/
static PartitionBoundSpec *
get_partition_bound_spec(Oid partOid, RangeVar *name)
@@ -5077,6 +5136,624 @@ get_partition_bound_spec(Oid partOid, RangeVar *name)
return boundspec;
}
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid, splitPartName);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * splitPartName: split partition name
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, splitPartName,
+ first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
+
/*
* calculate_partition_bound_for_merge
*
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 64248b5b1f..c0e918951a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..7765a9d365 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,11 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ RangeVar *splitPartName,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..eaccc46872
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1878 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..289591d496
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1165 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2826,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Fri, Jun 13, 2025 at 4:36 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi, Jian He!
Thanks for the notes and patches (again).
I read a part of emails, I hope to read the rest emails tomorrow.
hi.
in doc/src/sgml/ref/alter_table.sgml
<title>Parameters</title> section,
we also need explain
<replaceable class="parameter">partition_name1</replaceable>
and
<replaceable class="parameter">partition_name2</replaceable>
?
+ <para>
+ This form merges several partitions into the one partition of
the target table.
+ Hash-partitioning is not supported.
maybe we can change to
+ <para>
+ This form merges several partitions of the target table into a new
one partition.
+ Hash-partitioned target table is not supported
+ <para>
+ This command acquires an <literal>ACCESS EXCLUSIVE</literal> lock.
+ This is a significant limitation, which limits the usage of this
+ command with large partitioned tables under a high load.
+ </para>
would be better mentioning that the parent table and to be merged
partition will all take
<literal>ACCESS EXCLUSIVE</literal> lock.
for example, other places we have word like:
<para>
Attaching a partition acquires a
<literal>SHARE UPDATE EXCLUSIVE</literal> lock on the parent table,
in addition to the <literal>ACCESS EXCLUSIVE</literal> locks on the table
being attached and on the default partition (if any).
</para>
---------------------------------------------------------------------------------
+ <para>
+ For range- and list-partitioned tables the ranges and lists of values
+ of the merged partitions can be any.
+ </para>
we can change it to
<para>
For range-partitioned and list-partitioned tables, the partition
bounds specification can be arbitrary.
</para>
+ <para>
+ For range-partitioned tables it is necessary that the ranges
+ of the partitions <replaceable
class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>
[, ...] can
+ be merged into one range without spaces and overlaps
(otherwise an error
+ will be generated).
"without spaces and overlaps" seems not ideal, I think I found out the
perfect word for it: adjacent.
in [1], we have description like:
anyrange -|- anyrange → boolean
Are the ranges adjacent?
[1]: https://www.postgresql.org/docs/current/functions-range.html so we can change the above to
so we can change the above to
For range-partitioned tables, the ranges of the partitions partition_name1,
partition_name2, [...] must be adjacent in order to be merged. Otherwise, an
error will be raised. The resulting combined range will be the new
partition bound for the partition partition_name.
+ The new partition will have the same table access method as the parent.
+ If the parent table is persistent then the new partition is created
+ persistent. If the parent table is temporary then the new partition
+ is also created temporary. The new partition will also be created in
+ the same tablespace as the parent.
+ </para>
we can simplify the above as
" The new partition will inherit the same table access method, persistence
type, and tablespace as the parent table.
"
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new
partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
I think we also need to mention that individual ACL on the merged
partition will be dropped.
We have function signature
static void RemoveInheritance(Relation child_rel, Relation parent_rel,
bool expect_detached)
I found that "child_rel", "parent_rel" naming improves code
readability a lot for partitioned table contexts.
so we can change
+static void
+detachPartitionTable(Relation partRel, Relation rel, Oid defaultPartOid)
to
+static void
+detachPartitionTable(Relation partRel, Relation rel, Oid defaultPartOid)
We can also rename the ATExecMergePartitions argument (Relation rel)
to (Relation parent_rel), I think it will improve code reliability.
The attached patch is mainly documentation refactoring
and renaming function detachPartitionTable argument,
it is based on v44.
Attachments:
v44-0001-documentation-refactoring-based-on-v44.no-cfbotapplication/octet-stream; name=v44-0001-documentation-refactoring-based-on-v44.no-cfbotDownload
From c752b1c5e555fb0397b9c3a2ac918fa66584e615 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 13 Jun 2025 14:24:11 +0800
Subject: [PATCH v44 1/1] documentation refactoring based on v44
---
doc/src/sgml/ref/alter_table.sgml | 38 +++++++++++++++----------------
src/backend/commands/tablecmds.c | 10 ++++----
2 files changed, 24 insertions(+), 24 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 855d2ca44db..e49e3362b55 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1155,27 +1155,28 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
- This form merges several partitions into the one partition of the target table.
- Hash-partitioning is not supported. If <literal>DEFAULT</literal> partition is not in the
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
list of partitions <replaceable class="parameter">partition_name1</replaceable>,
<replaceable class="parameter">partition_name2</replaceable> [, ...]:
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables it is necessary that the ranges
- of the partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable> [, ...] can
- be merged into one range without spaces and overlaps (otherwise an error
- will be generated). The combined range will be the range for the partition
- <replaceable class="parameter">partition_name</replaceable>.
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
<listitem>
<para>
- For list-partitioned tables the value lists of all partitions
+ For list-partitioned tables, the partition bounds of
<replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable> [, ...] are
- combined and form the list of values of partition
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
@@ -1186,13 +1187,15 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The partition <replaceable class="parameter">partition_name</replaceable>
- will be the <literal>DEFAULT</literal> partition.
+ will be the new <literal>DEFAULT</literal> partition of the target table.
</para>
</listitem>
<listitem>
<para>
- For range- and list-partitioned tables the ranges and lists of values
- of the merged partitions can be any.
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
</para>
</listitem>
</itemizedlist>
@@ -1211,11 +1214,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
into the new partition.
Extended statistics aren't copied from the parent table, for consistency with
<command>CREATE TABLE PARTITION OF</command>.
- The new partition will have the same table access method as the parent.
- If the parent table is persistent then the new partition is created
- persistent. If the parent table is temporary then the new partition
- is also created temporary. The new partition will also be created in
- the same tablespace as the parent.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
</para>
<para>
When partitions are merged, any individual objects belonging to those
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 190ce952ade..c56b43c7fe5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22660,14 +22660,14 @@ moveMergedTablesRows(List **wqueue, Relation rel,
}
/*
- * detachPartitionTable: detach partition "partRel" from partitioned table
- * "rel" with default partition identifier "defaultPartOid"
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
*/
static void
-detachPartitionTable(Relation partRel, Relation rel, Oid defaultPartOid)
+detachPartitionTable(Relation child_rel, Relation parent_rel, Oid defaultPartOid)
{
/* Remove the pg_inherits row first. */
- RemoveInheritance(partRel, rel, false);
+ RemoveInheritance(child_rel, parent_rel, false);
/*
* Detaching the partition might involve TOAST table access, so ensure we
@@ -22676,7 +22676,7 @@ detachPartitionTable(Relation partRel, Relation rel, Oid defaultPartOid)
PushActiveSnapshot(GetTransactionSnapshot());
/* Do the final part of detaching. */
- DetachPartitionFinalize(rel, partRel, false, defaultPartOid);
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
PopActiveSnapshot();
}
--
2.34.1
Hi!
Additional changes (in attached patch):
a. Added using pull_varattnos to check whether a CHECK constraint
contains a reference to the tableoid column (only such CHECKs are
recalculated).
b. Added test for recomputation of stored generated columns.
1.
We can perform a preliminary check to determine whether dropping a
partition is allowed, and raise an error if it's not. To do it, I
invented a new function, performDeletionCheck to verify whether an
object can be safely dropped.
Applied. I moved calls performDeletionCheck a bit earlier, right after
detachPartitionTable. Is it ok?
2.
check_partitions_for_split does not exist in v43-0001.
Fixed.
+ RenameRelationInternal(RelationGetRelid(sameNamePartition), + tmpRelName, false, false); the third argument, is_internal should set to true?
Ok.
a partitioned table can not have NO INHERIT check constraint,
you may see StoreRelCheck.
we can add an Assert: Assert(!ccnoinherit);
Ok.
+ nnconstraints = + RelationGetNotNullConstraints(RelationGetRelid(modelRel), + false, true); as mentioned in above, partitioned table cannot have NO INHERIT constraint, maybe we should set RelationGetNotNullConstraints last argument to false
Ok.
The attached patch is a rewrite for
calculate_partition_bound_for_merge and callees.
please let me know whether this improves code readability
I think these changes can be taken partially.
MERGE PARTITIONS and SPLIT PARTITION commands use the same function
check_two_partitions_bounds_range. For MERGE PARTITIONS we can pass
Oids instead of RangeVars (first_name/second_name arguments).
But for SPLIT PARTITION we cannot do this, because at this stage the
new partitions have not yet been created (there are only their names).
Different realizations of check_two_partitions_bounds_range functions
for MERGE PARTITIONS and SPLIT PARTITION are not very good. I think it's
better not change the check_two_partitions_bounds_range function.
3.
v43-0001 doesn't have the SPLIT PARTITION feature.
maybe we need to remove the argument (bool defaultPart)
from check_two_partitions_bounds_range, aslo remove the comments.
then we can add it on 0002 SPLIT PARTITION patch.
Changed.
4. I don't know English very well, so it's difficult for me to correct
the documentation. Thank you very much for the corrections!
would be better mentioning that the parent table and to be merged
partition will all take <literal>ACCESS EXCLUSIVE</literal> lock.
Ok, updated.
Other email notes fixed in patch
v44-0001-documentation-refactoring-based-on-v44.no-cfbot
Patch applied.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v45-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v45-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 56230dd7082dd4fda9419c953062fc65e05b591c Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v45 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 104 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 887 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 143 ++
src/backend/partitioning/partbounds.c | 198 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1193 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 792 +++++++++++
22 files changed, 3671 insertions(+), 29 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..e503a06028 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1487,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1921,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968..5afc493820 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..7e7703c799 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,819 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in modelRel might reference
+ * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within moveMergedTablesRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = !ccvalid;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, true);
+
+ /*
+ * modelRel check constraint expresssion may reference tableoid, so later in
+ * moveMergedTablesRows, we need evulate the check constraint again for the
+ * newRel. We can check weather check constraint contain tableoid reference
+ * or not via pull_varattnos. But unconditionaly revaulate check cosntraint
+ * seems more safe.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Bitmapset *attnums = NULL;
+
+ pull_varattnos((Node *) ccon->expr, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = ccon->expr;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(modelRel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitionsList, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitionsList = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Lock all merged partitions, check them and create list with partitions
+ * contexts.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition: need to use
+ * exclusive lock for preventing DML-queries to the partition.
+ */
+ mergingPartition = table_openrv(name, AccessExclusiveLock);
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitionsList = lappend(mergingPartitionsList,
+ mergingPartition);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Relation sameNamePartition = NULL;
+
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ if (RelationGetRelid(mergingPartition) == existingRelid)
+ {
+ sameNamePartition = mergingPartition;
+ break;
+ }
+ }
+
+ if (sameNamePartition)
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(RelationGetRelid(sameNamePartition),
+ tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Detach all merged partitions.
+ *
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ ObjectAddress object;
+
+ detachPartitionTable(rel, mergingPartition, defaultPartOid);
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(wqueue, rel, mergingPartitionsList, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ {
+ ObjectAddress object;
+
+ /* Get relation id before table_close() call. */
+ object.objectId = RelationGetRelid(mergingPartition);
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ /* Keep the lock until commit. */
+ table_close(mergingPartition, NoLock);
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+ list_free(mergingPartitionsList);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..da29198644 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,133 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check that partRelOid is an oid of partition of the parent table rel
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = relation_open(partRelOid, AccessShareLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table",
+ RelationGetRelationName(partRel)));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition",
+ RelationGetRelationName(partRel)));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel),
+ RelationGetRelationName(rel)));
+
+ /* Permissions checks */
+ if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
+ aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
+ RelationGetRelationName(partRel));
+
+ relation_close(partRel, AccessShareLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3895,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 contain 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 4bdc2941ef..2664c7b709 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,3 +4978,196 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ 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 the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2c0b4f28c1..64248b5b1f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..4bfc4f7b5f
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1193 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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"
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition
+-- ERROR: "sales_external2" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition
+-- 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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..38cf4afbf1
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,792 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
+-- (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_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v45-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v45-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 2aec1a86faeba0e14c9b86163445b285fe6f898d Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v45 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 92 +-
src/backend/commands/tablecmds.c | 463 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 56 +-
src/backend/partitioning/partbounds.c | 684 +++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1905 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1188 ++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4725 insertions(+), 23 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e503a06028..daadb8326b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1244,7 +1313,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1488,7 +1558,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1921,6 +1991,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7e7703c799..f5cd09d3ed 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22888,3 +22910,444 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(List **wqueue, Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * We are going to detach and remove this partition: need to use exclusive
+ * lock for preventing DML-queries to the partition.
+ */
+ splitRel = table_openrv(cmd->name, AccessExclusiveLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index da29198644..cb356cabc9 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3529,6 +3529,37 @@ checkPartition(Relation rel, Oid partRelOid)
relation_close(partRel, AccessShareLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ splitPartOid = RangeVarGetRelid(partcmd->name, AccessShareLock, false);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3887,7 +3918,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3895,6 +3926,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3903,7 +3935,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4338,13 +4374,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4353,9 +4389,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4363,7 +4399,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 2664c7b709..f77f3d6a02 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4984,15 +4984,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5001,6 +5007,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,7 +5029,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5133,7 +5140,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5171,3 +5178,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 64248b5b1f..c0e918951a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..aa34440c65
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1905 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..f816c91597
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1188 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" conflicts with upper bound of previous partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_error" conflicts with upper bound of previous partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8346cda63..56ac447288 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2760,6 +2760,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2826,6 +2827,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
static void checkPartition(Relation rel, Oid partRelOid)
function name checkPartition is not ideal, maybe we can change it to
CheckPartitionForMerge or MergePartitionCheck.
(attached v45-002 is error message refactoring for checkPartition,
I didn't change the name though.)
For the command:
ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk_1;
Acquiring AccessExclusiveLock on the partitions to be merged
(pk_1, pk_2) during transformPartitionCmdForMerge should be fine, IMHO.
Here’s why:
* The merged partitions (pk_1, pk_2) will be dropped in the end, so acquiring
AccessExclusiveLock is unavoidable for ALTER TABLE MERGE PARTITIONS.
* Taking an AccessShareLock first, then later acquiring AccessExclusiveLock
in ATExecMergePartitions unnecessarily wastes resources.
(acquire two locks, one stronger should be enough)
* Acquiring AccessExclusiveLock first helps avoid potential anomalies
caused by concurrent operations.
The attached patch refactors transformPartitionCmdForMerge and
ATExecMergePartitions based on the idea of acquiring AccessExclusiveLock on the
to be merged partitions during transformPartitionCmdForMerge
+ * Callback allows caller to check permissions or acquire additional locks
+ * prior to grabbing the relation lock.
Please see the above comments in RangeVarGetRelidExtended.
+ /*
+ * Search DEFAULT partition in the list. Lock partitions before
+ * calculating the boundary for resulting partition.
+ */
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
so the above transformPartitionCmdForMerge does not check if the
currently user have permission
or not, directly take a lock on RangeVar, name, which is a bug, we should
first do permission check then acquire a lock.
Attachments:
v45-0001-refactor-ATExecMergePartitions-transformPartitionCmdF.no-cfbotapplication/octet-stream; name=v45-0001-refactor-ATExecMergePartitions-transformPartitionCmdF.no-cfbotDownload
From 97f4372b6c1f4eb282b7a3e09e860abe9a27cae1 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Sun, 15 Jun 2025 22:24:26 +0800
Subject: [PATCH v45 1/2] refactor ATExecMergePartitions,
transformPartitionCmdForMerge
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
For the command:
ALTER TABLE pk MERGE PARTITIONS (pk_1, pk_2) INTO pk_1;
I believe we should acquire AccessExclusiveLock on the partitions to be merged
(pk_1, pk_2) during transformPartitionCmdForMerge. Here’s why:
* The merged partitions (pk_1, pk_2) will be dropped in the end, so acquiring
AccessExclusiveLock is unavoidable for ALTER TABLE MERGE PARTITIONS.
* Taking an AccessShareLock first, and then later acquiring AccessExclusiveLock in
ATExecMergePartitions unnecessarily waste resources.
* Acquiring AccessExclusiveLock first helps avoid potential anomalies caused by concurrent operations.
+ partOid = RangeVarGetRelid(name, AccessShareLock, false);
if current user don't owne the table (name), then he can not lock the table.
thus the above code in transformPartitionCmdForMerge need refactor
---
src/backend/commands/tablecmds.c | 74 +++++++++++++++++-------------
src/backend/parser/parse_utilcmd.c | 18 ++++++--
2 files changed, 56 insertions(+), 36 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7e7703c7997..e3bbfd9283b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22543,13 +22543,13 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
}
/*
- * moveMergedTablesRows: scan partitions to be merged (mergingPartitionsList)
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitions)
* of the partitioned table (rel) and move rows into the new partition
* (newPartRel). We also reevaulate check constraints against these rows.
*/
static void
moveMergedTablesRows(List **wqueue, Relation rel,
- List *mergingPartitionsList, Relation newPartRel)
+ List *mergingPartitions, Relation newPartRel)
{
CommandId mycid;
EState *estate;
@@ -22580,12 +22580,15 @@ moveMergedTablesRows(List **wqueue, Relation rel,
/* Create necessary tuple slot. */
dstslot = table_slot_create(newPartRel, NULL);
- foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ foreach_oid(merging_oid, mergingPartitions)
{
TupleTableSlot *srcslot;
TupleConversionMap *tuple_map;
TableScanDesc scan;
Snapshot snapshot;
+ Relation mergingPartition;
+
+ mergingPartition = table_open(merging_oid, NoLock);
/* Create tuple slot for new partition. */
srcslot = table_slot_create(mergingPartition, NULL);
@@ -22659,6 +22662,7 @@ moveMergedTablesRows(List **wqueue, Relation rel,
free_conversion_map(tuple_map);
ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
}
FreeExecutorState(estate);
@@ -22709,7 +22713,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context)
{
Relation newPartRel;
- List *mergingPartitionsList = NIL;
+ List *mergingPartitions = NIL;
Oid defaultPartOid;
Oid existingRelid;
Oid ownerId = InvalidOid;
@@ -22718,18 +22722,21 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
int save_nestlevel;
/*
- * Lock all merged partitions, check them and create list with partitions
- * contexts.
- */
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
foreach_node(RangeVar, name, cmd->partlist)
{
Relation mergingPartition;
/*
- * We are going to detach and remove this partition: need to use
- * exclusive lock for preventing DML-queries to the partition.
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
*/
- mergingPartition = table_openrv(name, AccessExclusiveLock);
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
if (OidIsValid(ownerId))
{
@@ -22743,8 +22750,10 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
ownerId = mergingPartition->rd_rel->relowner;
/* Store a next merging partition into the list. */
- mergingPartitionsList = lappend(mergingPartitionsList,
- mergingPartition);
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
}
/*
@@ -22764,18 +22773,18 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
*/
if (OidIsValid(existingRelid))
{
- Relation sameNamePartition = NULL;
+ Oid new_partition = InvalidOid;
- foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ foreach_oid(mergingPartition, mergingPartitions)
{
- if (RelationGetRelid(mergingPartition) == existingRelid)
+ if (mergingPartition == existingRelid)
{
- sameNamePartition = mergingPartition;
+ new_partition = mergingPartition;
break;
}
}
- if (sameNamePartition)
+ if (OidIsValid(new_partition))
{
/*
* The new partition has the same name as one of merging
@@ -22792,8 +22801,7 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* in the future because we're going to eventually drop the
* existing partition anyway.
*/
- RenameRelationInternal(RelationGetRelid(sameNamePartition),
- tmpRelName, true, false);
+ RenameRelationInternal(new_partition, tmpRelName, true, false);
/*
* We must bump the command counter to make the new partition
@@ -22822,14 +22830,23 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* merge process (moveMergedTablesRows) can be time-consuming, performing an
* early check on the drop eligibility of old partitions is preferable.
*/
- foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ foreach_oid(mergingPartition, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartition, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ foreach_oid(mergingPartition, mergingPartitions)
{
ObjectAddress object;
- detachPartitionTable(rel, mergingPartition, defaultPartOid);
-
/* Get oid of the later to be dropped relation */
- object.objectId = RelationGetRelid(mergingPartition);
+ object.objectId = mergingPartition;
object.classId = RelationRelationId;
object.objectSubId = 0;
@@ -22854,24 +22871,19 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
RestrictSearchPath();
/* Copy data from merged partitions to new partition. */
- moveMergedTablesRows(wqueue, rel, mergingPartitionsList, newPartRel);
+ moveMergedTablesRows(wqueue, rel, mergingPartitions, newPartRel);
/* Drop the current partitions before attaching the new one. */
- foreach_ptr(RelationData, mergingPartition, mergingPartitionsList)
+ foreach_oid(mergingPartition, mergingPartitions)
{
ObjectAddress object;
- /* Get relation id before table_close() call. */
- object.objectId = RelationGetRelid(mergingPartition);
+ object.objectId = mergingPartition;
object.classId = RelationRelationId;
object.objectSubId = 0;
- /* Keep the lock until commit. */
- table_close(mergingPartition, NoLock);
-
performDeletion(&object, DROP_RESTRICT, 0);
}
- list_free(mergingPartitionsList);
/*
* Attach a new partition to the partitioned table. wqueue = NULL:
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index da291986446..eb8a937e1e8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3500,7 +3500,7 @@ checkPartition(Relation rel, Oid partRelOid)
{
Relation partRel;
- partRel = relation_open(partRelOid, AccessShareLock);
+ partRel = table_open(partRelOid, NoLock);
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
@@ -3526,7 +3526,7 @@ checkPartition(Relation rel, Oid partRelOid)
aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
RelationGetRelationName(partRel));
- relation_close(partRel, AccessShareLock);
+ table_close(partRel, NoLock);
}
/*
@@ -3577,10 +3577,18 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
}
/*
- * Search DEFAULT partition in the list. Lock partitions before
- * calculating the boundary for resulting partition.
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
*/
- partOid = RangeVarGetRelid(name, AccessShareLock, false);
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
if (partOid == defaultPartOid)
isDefaultPart = true;
--
2.34.1
v45-0002-error-message-refactoring.no-cfbotapplication/octet-stream; name=v45-0002-error-message-refactoring.no-cfbotDownload
From b73cc0afd61b588a17528f59901334c1839fc33e Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Mon, 16 Jun 2025 11:54:41 +0800
Subject: [PATCH v45 2/2] error message refactoring
---
src/backend/parser/parse_utilcmd.c | 20 ++++++++-----------
src/backend/partitioning/partbounds.c | 3 ++-
src/test/regress/expected/partition_merge.out | 18 ++++++++++++-----
3 files changed, 23 insertions(+), 18 deletions(-)
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index eb8a937e1e8..4fe9cd33328 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3493,7 +3493,7 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
- * Check that partRelOid is an oid of partition of the parent table rel
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
*/
static void
checkPartition(Relation rel, Oid partRelOid)
@@ -3505,26 +3505,22 @@ checkPartition(Relation rel, Oid partRelOid)
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
- RelationGetRelationName(partRel)));
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a partition",
- RelationGetRelationName(partRel)));
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
- RelationGetRelationName(partRel),
- RelationGetRelationName(rel)));
-
- /* Permissions checks */
- if (!object_ownercheck(RelationRelationId, RelationGetRelid(partRel), GetUserId()))
- aclcheck_error(ACLCHECK_NOT_OWNER, get_relkind_objtype(partRel->rd_rel->relkind),
- RelationGetRelationName(partRel));
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 2664c7b7091..9f7c01b7fa8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5028,8 +5028,9 @@ check_two_partitions_bounds_range(Relation parent,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"",
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 4bfc4f7b5ff..20fa6c13680 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -29,14 +29,17 @@ LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
-- ERROR: "sales_apr2022" is not a table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
-- ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022"
-- (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: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
-- ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021"
-- (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"
+ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
ERROR: partition with name "sales_feb2022" is already used
@@ -611,13 +614,16 @@ CREATE TABLE sales_external (LIKE sales_list);
CREATE TABLE sales_external2 (vch VARCHAR(5));
-- ERROR: "sales_external" is not a partition
ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
-ERROR: "sales_external" is not a partition
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
-- ERROR: "sales_external2" is not a partition
ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
-ERROR: "sales_external2" is not a partition
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
DROP TABLE sales_external2;
DROP TABLE sales_external;
DROP TABLE sales_list2;
@@ -759,9 +765,11 @@ CREATE TABLE t3 (i int, t text);
-- ERROR: relation "t1p1" is not a partition of relation "t2"
ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
-- ERROR: "t3" is not a partition
ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
-ERROR: "t3" is not a partition
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
2.34.1
for v45.
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Bitmapset *attnums = NULL;
+
+ pull_varattnos((Node *) ccon->expr, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber -
FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = ccon->expr;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
we need to expand the virtual generated column here,
otherwise, bms_is_member would be not correct.
consider case like:
CREATE TABLE pp (f1 INT, f2 INT generated always as (f1 +
tableoid::int)) PARTITION BY RANGE (f1);
CREATE TABLE pp_1 (f2 INT generated always as (f1 + tableoid::int), f1 int);
ALTER TABLE pp ATTACH PARTITION pp_1 FOR VALUES FROM (-1) TO (10);
CREATE TABLE pp_2 (f2 INT generated always as (f1 + tableoid::int), f1 int);
ALTER TABLE pp ATTACH PARTITION pp_2 FOR VALUES FROM (10) TO (20);
ALTER TABLE PP add check (f2 > 0);
ALTER TABLE pp MERGE PARTITIONS (pp_1, pp_2) INTO pp_12;
In this context, the merge partition command needs to evaluate the constraint
"pp_f2_check" again on pp_12.
attach minor diff fix this problem.
Attachments:
check_constraint_if_it_contains_tableoid.no-cfbotapplication/octet-stream; name=check_constraint_if_it_contains_tableoid.no-cfbotDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7e7703c7997..179eab10c84 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22367,16 +22367,17 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
* modelRel check constraint expresssion may reference tableoid, so later in
* moveMergedTablesRows, we need evulate the check constraint again for the
* newRel. We can check weather check constraint contain tableoid reference
- * or not via pull_varattnos. But unconditionaly revaulate check cosntraint
- * seems more safe.
+ * or not via pull_varattnos.
*/
foreach_ptr(CookedConstraint, ccon, cookedConstraints)
{
if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
{
+ Node *qual;
Bitmapset *attnums = NULL;
- pull_varattnos((Node *) ccon->expr, 1, &attnums);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
/*
* Add check only if it contains tableoid
@@ -22390,7 +22391,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
newcon->name = ccon->name;
newcon->contype = ccon->contype;
- newcon->qual = ccon->expr;
+ newcon->qual = qual;
tab->constraints = lappend(tab->constraints, newcon);
}
Hi!
1.
function name checkPartition is not ideal, maybe we can change it to
CheckPartitionForMerge or MergePartitionCheck.
I agree that this name is not ideal. But the "checkPartition" function
is used for both MERGE/SPLIT commands, so the word 'Merge' in the
prefix or suffix of the function name would not be correct ...
May be "checkPartitionForModification" or something like that?
The attached patch refactors transformPartitionCmdForMerge and
ATExecMergePartitions based on the idea of acquiring
AccessExclusiveLock on the to be merged partitions during
transformPartitionCmdForMerge
Thanks, applied.
2.
we need to expand the virtual generated column here,
otherwise, bms_is_member would be not correct.
...
attach minor diff fix this problem.
Added patch and a bit modified test.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v46-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v46-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 1b290e06539f5768962c4457605b24197d0ecf50 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v46 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 104 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 906 +++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 148 ++
src/backend/partitioning/partbounds.c | 199 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/catalog/heap.h | 3 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1234 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 816 +++++++++++
22 files changed, 3761 insertions(+), 29 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..e503a06028 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1487,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1921,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968..5afc493820 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..571b6b0574 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
@@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-static void
+void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..9a9053d325 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,838 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in modelRel might reference
+ * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within moveMergedTablesRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ CookedConstraint *cooked;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
+ cooked->contype = CONSTR_CHECK;
+ cooked->conoid = InvalidOid;
+ cooked->name = ccname;
+ cooked->attnum = 0;
+ cooked->expr = ccbin_node;
+ cooked->is_enforced = ccenforced;
+ cooked->skip_validation = !ccvalid;
+ cooked->is_local = true;
+ cooked->inhcount = 0;
+ cooked->is_no_inherit = ccnoinherit;
+ cookedConstraints = lappend(cookedConstraints, cooked);
+ }
+
+ /* Store CHECK constraints. */
+ StoreConstraints(newRel, cookedConstraints, true);
+
+ /*
+ * modelRel check constraint expresssion may reference tableoid, so later in
+ * moveMergedTablesRows, we need evulate the check constraint again for the
+ * newRel. We can check weather check constraint contain tableoid reference
+ * or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(modelRel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Detach all merged partitions.
+ *
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(wqueue, rel, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..f55ad17528 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3900,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 contain 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 4bdc2941ef..9f7c01b7fa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,3 +4978,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2c0b4f28c1..64248b5b1f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index dbd339e9df..c130bc0c38 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
+extern void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
+
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..1cd34fae2d
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1234 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ 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_others | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
+------------------------------------------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.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_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+select * from sales_others;
+ salesperson_id | salesperson_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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | p
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..5baba56392
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,816 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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;
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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_schema2';
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.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 (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 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 testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v46-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v46-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 5411bff81bd8b6240efd06e9a6169e768959fecf Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v46 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 92 +-
src/backend/commands/tablecmds.c | 463 ++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 65 +-
src/backend/partitioning/partbounds.c | 684 +++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1911 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1188 ++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4740 insertions(+), 23 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e503a06028..daadb8326b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1244,7 +1313,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1488,7 +1558,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1921,6 +1991,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9a9053d325..789c6828d9 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22907,3 +22929,444 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(List **wqueue, Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index f55ad17528..73315efac8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,46 @@ checkPartition(Relation rel, Oid partRelOid)
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3892,7 +3932,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3900,6 +3940,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3908,7 +3949,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4343,13 +4388,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4358,9 +4403,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4368,7 +4413,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9f7c01b7fa..9c730e127c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4984,15 +4984,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5001,6 +5007,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,7 +5029,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5134,7 +5141,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5172,3 +5179,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 64248b5b1f..c0e918951a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..d4519fbdbe
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1911 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | 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;
+ salesperson_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;
+ salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+------------------+------------+-------------+-----------+------------+------------------
+ Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+(4 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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 SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+ Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ Manager3 | 2022 | 2 | 1 | 2022.02.01 | 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;
+ salesperson_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;
+ salesperson_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 | 1 | 10 | 2022.01.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_feb2022;
+ salesperson_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
+ Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(3 rows)
+
+SELECT * FROM sales_other;
+ salesperson_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)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2022"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+(2 rows)
+
+SELECT * FROM salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+SELECT * FROM salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT * FROM salespeople1_2;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople2_3;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 2 | Ivanov
+(1 row)
+
+SELECT * FROM salespeople3_4;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 3 | May
+(1 row)
+
+SELECT * FROM salespeople4_5;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 4 | Ford
+(1 row)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_20;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+(2 rows)
+
+select * from salespeople20_30;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 20 | Smirnoff
+(1 row)
+
+select * from salespeople30_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 30 | Ford
+(1 row)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 4 | Ivanov | 750 | 04-13-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_20_30;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+(1 row)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+SELECT * FROM sales_west;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+(4 rows)
+
+SELECT * FROM sales_east;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+(2 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Oslo | 1200 | 03-06-2022
+ 9 | May | Oslo | 1200 | 03-11-2022
+ 10 | Halder | Helsinki | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_central;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(4 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT * FROM sales_jan2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 13 | Gandi | 377 | 01-09-2022
+(1 row)
+
+SELECT * FROM sales_feb2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-09-2022
+ 6 | Poirot | 150 | 02-07-2022
+(2 rows)
+
+SELECT * FROM sales_mar2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+(1 row)
+
+SELECT * FROM sales_apr2022_1decade;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(2 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+ 1 | May | 1000 | 01-31-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+(8 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-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
+(14 rows)
+
+SELECT * FROM sales_jan2022;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..b62d7dc30d
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1188 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan_feb2022;
+SELECT * FROM sales_other;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT * FROM sales_date;
+SELECT * FROM sales_dec2022;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_other;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2022 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2022 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2022 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2022 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_20;
+SELECT * FROM salespeople20_30;
+SELECT * FROM salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT * FROM salespeople1_2;
+SELECT * FROM salespeople2_3;
+SELECT * FROM salespeople3_4;
+SELECT * FROM salespeople4_5;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+select * from salespeople01_10;
+select * from salespeople10_20;
+select * from salespeople20_30;
+select * from salespeople30_40;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+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;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_west;
+SELECT * FROM sales_east;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_central;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT * FROM sales_jan2022_1decade;
+SELECT * FROM sales_feb2022_1decade;
+SELECT * FROM sales_mar2022_1decade;
+SELECT * FROM sales_apr2022_1decade;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 32d6e718ad..b815cced84 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2766,6 +2766,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2832,6 +2833,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Tue, Jun 17, 2025 at 4:15 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Added patch and a bit modified test.
hi.
Please check the attached patch for addressing the following issues.
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
There are no regress tests for this, I have added a simple test for it.
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;
I found about 10 similar queries in partition_merge. We can replace them with
prepared statement—parsing once and executing multiple times. This not only
improves the readability of the test code but also slightly speeds up test
execution.
there are some test code pattern like:
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
+SELECT * FROM sales_others;
since sales_jan2022, sales_feb_mar_apr2022, sales_others
are partition of sales_range, we can simply use
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid,
salesperson_id;
After applying the attached patch, partition_merge.out size is 61379
without the size is: 66145.
The attached patch also addressed issues raised from Álvaro Herrera in [1]/messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql.
instead of making function StoreConstraints external, using
AddRelationNewConstraints to install check constraints for new relation
in createTableConstraints
[1]: /messages/by-id/202502031640.zem6orjmmxoz@alvherre.pgsql
Attachments:
v46-0001-regress-test-refactoring-and-others.no-cfbotapplication/octet-stream; name=v46-0001-regress-test-refactoring-and-others.no-cfbotDownload
From 17ed8a55544c0cba0b77ef81f75f14326ebe9a6c Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Tue, 17 Jun 2025 15:47:11 +0800
Subject: [PATCH v46 1/1] regress test refactoring and others
main changes:
1. regress test refactoring
2. not export function StoreConstraints, using AddRelationNewConstraints
---
src/backend/catalog/heap.c | 4 +-
src/backend/commands/tablecmds.c | 36 +-
src/include/catalog/heap.h | 3 -
src/test/regress/expected/partition_merge.out | 327 ++++++------------
src/test/regress/sql/partition_merge.sql | 84 ++---
5 files changed, 163 insertions(+), 291 deletions(-)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 571b6b05749..54c95e42598 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,6 +102,8 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
@@ -2294,7 +2296,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
* expressions can be added later, by direct calls to StoreAttrDefault
* and StoreRelCheck (see AddRelationNewConstraints()).
*/
-void
+static void
StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal)
{
int numchecks = 0;
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9a9053d3252..b724e2d7150 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22227,6 +22227,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
AttrMap *attmap;
AttrNumber parent_attno;
int ccnum;
+ List *Constraints = NIL;
List *cookedConstraints = NIL;
tupleDesc = RelationGetDescr(modelRel);
@@ -22319,7 +22320,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
bool ccvalid = constr->check[ccnum].ccvalid;
Node *ccbin_node;
bool found_whole_row;
- CookedConstraint *cooked;
+ Constraint *constr;
/*
* Partitioned table can not have NO INHERIT check constraint (see
@@ -22346,22 +22347,27 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
ccname,
RelationGetRelationName(modelRel)));
- cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint));
- cooked->contype = CONSTR_CHECK;
- cooked->conoid = InvalidOid;
- cooked->name = ccname;
- cooked->attnum = 0;
- cooked->expr = ccbin_node;
- cooked->is_enforced = ccenforced;
- cooked->skip_validation = !ccvalid;
- cooked->is_local = true;
- cooked->inhcount = 0;
- cooked->is_no_inherit = ccnoinherit;
- cookedConstraints = lappend(cookedConstraints, cooked);
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
}
- /* Store CHECK constraints. */
- StoreConstraints(newRel, cookedConstraints, true);
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
/*
* modelRel check constraint expresssion may reference tableoid, so later in
diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h
index c130bc0c38d..dbd339e9df4 100644
--- a/src/include/catalog/heap.h
+++ b/src/include/catalog/heap.h
@@ -119,9 +119,6 @@ extern List *AddRelationNotNullConstraints(Relation rel,
List *constraints,
List *old_notnulls);
-extern void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
-
extern void RelationClearMissing(Relation rel);
extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum,
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 1cd34fae2d5..f1a6b4b1b25 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -45,6 +45,9 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitio
ERROR: partition with name "sales_feb2022" is already used
LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
-- NO ERROR: test for custom partitions order, source partitions not in the search_path
SET search_path = partitions_merge_schema2, public;
ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
@@ -52,16 +55,23 @@ ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
partitions_merge_schema.sales_mar2022,
partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
SET search_path = partitions_merge_schema, public;
-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
-------------------------------------------------+---------+------------------+--------------------------------------------------
- partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
- 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_others | r | f | DEFAULT
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
(4 rows)
DROP TABLE sales_range;
@@ -97,31 +107,25 @@ SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
(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
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
(5 rows)
-- check schema-qualified name of the new partition
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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
-------------------------------------------------+---------+------------------+--------------------------------------------------
- partitions_merge_schema2.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
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
(3 rows)
SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
@@ -130,54 +134,25 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemanam
partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
(1 row)
-SELECT * FROM sales_range;
- salesperson_id | salesperson_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
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
(14 rows)
-SELECT * FROM sales_jan2022;
- salesperson_id | salesperson_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 partitions_merge_schema2.sales_feb_mar_apr2022;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
-(1 row)
-
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
@@ -226,28 +201,25 @@ INSERT INTO sales_range VALUES
-- name
ALTER TABLE sales_range MERGE PARTITIONS
(sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
-select * from sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
salesperson_id | salesperson_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
+ 10 | Halder | 350 | 01-28-2022
12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-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
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
(3 rows)
DROP TABLE sales_range;
@@ -503,89 +475,23 @@ INSERT INTO sales_range VALUES
(12, 'Plato', 350, '2022-03-19'),
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT * FROM sales_range;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_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
+SELECT tableoid::regclass, * FROM sales_apr2022;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
(4 rows)
-SELECT * FROM sales_apr2022_01_10;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 4 | Ivanov | 750 | 04-13-2022
-(1 row)
-
-SELECT * FROM sales_apr2022_20_30;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_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;
- salesperson_id | salesperson_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
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
(4 rows)
DROP TABLE sales_range;
@@ -661,30 +567,24 @@ INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date)
('Gandi', 'Warsaw', 150, '2022-03-08'),
('Plato', 'Lisbon', 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 ('Warsaw', 'Berlin', 'Kyiv')
- sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
- sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
- sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
- sales_others | r | f | DEFAULT
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | 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 ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
- sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
- sales_others | r | f | DEFAULT
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
(3 rows)
SELECT * FROM sales_list;
@@ -779,25 +679,19 @@ DROP TABLE t1;
CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
- oid | pg_get_expr | relpersistence
---------+----------------------------+----------------
- tp_0_1 | FOR VALUES FROM (0) TO (1) | t
- tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
(2 rows)
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
-- Partition should be temporary.
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
- oid | pg_get_expr | relpersistence
---------+----------------------------+----------------
- tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
(1 row)
DROP TABLE t;
@@ -839,14 +733,11 @@ SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c W
t | p
(1 row)
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
- oid | pg_get_expr | relpersistence
---------+----------------------------+----------------
- tp_0_1 | FOR VALUES FROM (0) TO (1) | p
- tp_1_2 | FOR VALUES FROM (1) TO (2) | p
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
(2 rows)
SET search_path = pg_temp, partitions_merge_schema, public;
@@ -869,16 +760,14 @@ SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c W
t | t
(1 row)
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
- oid | pg_get_expr | relpersistence
---------+----------------------------+----------------
- tp_0_1 | FOR VALUES FROM (0) TO (1) | t
- tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
(2 rows)
+DEALLOCATE get_partition_info;
SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 5baba56392f..320e1c3e8df 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -39,6 +39,8 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sal
ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
-- NO ERROR: test for custom partitions order, source partitions not in the search_path
SET search_path = partitions_merge_schema2, public;
@@ -48,10 +50,18 @@ ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
SET search_path = partitions_merge_schema, public;
-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;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
DROP TABLE sales_range;
@@ -85,26 +95,17 @@ INSERT INTO sales_range VALUES
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;
+EXECUTE get_partition_info('{sales_range}');
-- check schema-qualified name of the new partition
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.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;
+EXECUTE get_partition_info('{sales_range}');
SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
-SELECT * FROM sales_range;
-SELECT * FROM sales_jan2022;
-SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022;
-SELECT * FROM sales_others;
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
@@ -147,13 +148,10 @@ INSERT INTO sales_range VALUES
ALTER TABLE sales_range MERGE PARTITIONS
(sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others;
-select * from sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
-- 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;
+EXECUTE get_partition_info('{sales_range}');
DROP TABLE sales_range;
@@ -323,17 +321,11 @@ INSERT INTO sales_range VALUES
(13, 'Gandi', 377, '2022-01-09'),
(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;
+SELECT tableoid::regclass, * FROM sales_apr2022;
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;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
DROP TABLE sales_range;
@@ -415,18 +407,12 @@ INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date)
('Plato', 'Lisbon', 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;
+EXECUTE get_partition_info('{sales_list}');
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;
+EXECUTE get_partition_info('{sales_list}');
SELECT * FROM sales_list;
SELECT * FROM sales_nord;
@@ -468,18 +454,12 @@ CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+EXECUTE get_partition_info('{t}');
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
-- Partition should be temporary.
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+EXECUTE get_partition_info('{t}');
DROP TABLE t;
@@ -510,10 +490,8 @@ CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+EXECUTE get_partition_info('{t}');
SET search_path = pg_temp, partitions_merge_schema, public;
@@ -534,10 +512,10 @@ CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
-SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
- FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
- WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
- ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
SET search_path = partitions_merge_schema, pg_temp, public;
--
2.34.1
Hi!
v46-0001-regress-test-refactoring-and-others.no-cfbot
Thanks, applied. Two comments:
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
There are no regress tests for this, I have added a simple test for it.
Test for this is in the second commit (SPLIT PARTITION) but
it's okay to have test here.
+SELECT tableoid::regclass, * FROM sales_range ORDER BY ...
Similar changes are also made for SPLIT PARTITION.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v47-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v47-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From a45ee53d9e475262a4834a53fb141613f34f3114 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v47 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 104 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 912 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 148 +++
src/backend/partitioning/partbounds.c | 199 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1123 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 794 ++++++++++++
21 files changed, 3632 insertions(+), 28 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..e503a06028 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1487,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1921,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968..5afc493820 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fbaed5359a..54c95e4259 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..b724e2d715 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,844 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: return list of columns (ColumnDef) like model table
+ * (modelRel)
+ */
+static List *
+getAttributesList(Relation modelRel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(modelRel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints: create constraints, default values and generated
+ * values (prototype is function expandTableLikeClause).
+ * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation modelRel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(modelRel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(modelRel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(modelRel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(modelRel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in modelRel might reference
+ * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within moveMergedTablesRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(modelRel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * modelRel check constraint expresssion may reference tableoid, so later in
+ * moveMergedTablesRows, we need evulate the check constraint again for the
+ * newRel. We can check weather check constraint contain tableoid reference
+ * or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable: create table for a new partition with given name
+ * (newPartName) like table (modelRel, partitioned table). ownerId is
+ * determined by the partition on which the operation is performed, so it
+ * is passed separately.
+ *
+ * Also, this function sets the new partition access method same as parent
+ * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
+ * checks that parent and child tables have compatible persistence.
+ *
+ * Function returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation modelRel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(modelRel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(modelRel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(modelRel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Detach all merged partitions.
+ *
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ moveMergedTablesRows(wqueue, rel, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..f55ad17528 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3900,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 contain 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 4bdc2941ef..9f7c01b7fa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,3 +4978,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2c0b4f28c1..64248b5b1f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..f5e6ec6184
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1123 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM sales_list;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+SELECT * FROM sales_nord;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+----------------+--------------+------------
+ 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ 7 | May | Helsinki | 1200 | 03-06-2022
+ 9 | May | Helsinki | 1200 | 03-11-2022
+ 10 | Halder | Oslo | 800 | 03-02-2022
+(4 rows)
+
+SELECT * FROM sales_all;
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 2 | Smirnoff | New York | 500 | 03-03-2022
+ 5 | Deev | Lisbon | 250 | 03-07-2022
+ 11 | Muller | Madrid | 650 | 03-05-2022
+ 14 | Plato | Lisbon | 950 | 03-05-2022
+ 1 | Trump | Bejing | 1000 | 03-01-2022
+ 8 | Li | Vladivostok | 1150 | 03-09-2022
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 6 | Poirot | Berlin | 1000 | 03-01-2022
+ 12 | Smith | Kyiv | 350 | 03-10-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(10 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..2cdd58b200
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,794 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT * FROM sales_list;
+SELECT * FROM sales_nord;
+SELECT * FROM sales_all;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v47-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v47-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From dd7741235b60ae99144a8b699e875cd3c1dface2 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v47 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 92 +-
src/backend/commands/tablecmds.c | 463 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 65 +-
src/backend/partitioning/partbounds.c | 684 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1655 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1148 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4444 insertions(+), 23 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e503a06028..daadb8326b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1244,7 +1313,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1488,7 +1558,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1921,6 +1991,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b724e2d715..70ddf7a050 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22913,3 +22935,444 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * moveSplitTableRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+moveSplitTableRows(List **wqueue, Relation rel, Relation splitRel, List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via moveMergedTablesRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (moveMergedTablesRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ moveSplitTableRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index f55ad17528..73315efac8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,46 @@ checkPartition(Relation rel, Oid partRelOid)
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3892,7 +3932,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3900,6 +3940,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3908,7 +3949,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4343,13 +4388,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4358,9 +4403,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4368,7 +4413,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9f7c01b7fa..9c730e127c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4984,15 +4984,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5001,6 +5007,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,7 +5029,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5134,7 +5141,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5172,3 +5179,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 64248b5b1f..c0e918951a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7d543ab813
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1655 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..7fa4b69376
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1148 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 32d6e718ad..b815cced84 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2766,6 +2766,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2832,6 +2833,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
The following are changes I made based on v47.
mainly comments refactoring, variable/argument renaming.
please see the attached patch.
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ modelRel->rd_rel->reltablespace,
+....
+ allowSystemTableMods,
+ false,
+ InvalidOid,
+ NULL);
heap_create_with_catalog parameter is_internal should be set to true.
+ /*
+ * Construct a map from the LIKE relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
this comment in createTableConstraints is confusing, especially the word "LIKE".
I didn' change it though.
+/*
+ * moveMergedTablesRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table (rel) and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+moveMergedTablesRows(List **wqueue, Relation rel,
+ List *mergingPartitions, Relation newPartRel)
the argument (Relation rel) never used in moveMergedTablesRows
we can remove it, or rename it as "parent_rel".
I didn' change it though.
moveMergedTablesRows was never used in SPLIT PARTITION,
so maybe we can rename it to
ATMergePartitionMoveTablesRows
or
ATMergePartitionMoveRows
or
ATMergePartitionRows
what do you think?
check_two_partitions_bounds_range
we can name it to
range_partition_bounds_check
I don't have a huge opinion though.
createTableConstraints(List **wqueue, AlteredTableInfo *tab,
Relation modelRel, Relation newRel)
rename argument (Relation modelRel) to parent_rel,
I think it will improve readability, since "parent_rel" can tell you it's a
partitioned table.
ATExecMergePartitions some comments position adjusted.
minor change src/test/regress/sql/partition_merge.sql
-SELECT * FROM sales_list;
-SELECT * FROM sales_nord;
-SELECT * FROM sales_all;
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
we need an error case for
ERROR: cannot drop table \"%s\" because other objects depend on it
so I added a test for it. as you can see below, the error HINT message
is not great in this
context.
CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022,
sales_feb2022) INTO sales_dec_jan_feb2022;
ERROR: cannot drop table sales_jan2022 because other objects depend on it
DETAIL: view jan2022v depends on table sales_jan2022
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP VIEW jan2022v;
Attachments:
v47-0001-rename-function-argument-and-minor-refactor.no-cfbotapplication/octet-stream; name=v47-0001-rename-function-argument-and-minor-refactor.no-cfbotDownload
From 1b25410e75a2029c3aec7f455bcb48e6cdac241e Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 18 Jun 2025 10:40:39 +0800
Subject: [PATCH v47 1/1] rename function argument and minor refactor
* rename "rel" or "modelRel" to "parent_rel" to improve code readability
* comments refactoring
* minor tests changes.
---
src/backend/commands/tablecmds.c | 98 +++++++++----------
src/test/regress/expected/partition_merge.out | 64 +++++-------
src/test/regress/sql/partition_merge.sql | 8 +-
3 files changed, 75 insertions(+), 95 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index b724e2d7150..d7d0e349b19 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22158,17 +22158,16 @@ evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
}
/*
- * getAttributesList: return list of columns (ColumnDef) like model table
- * (modelRel)
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
*/
static List *
-getAttributesList(Relation modelRel)
+getAttributesList(Relation parent_rel)
{
AttrNumber parent_attno;
TupleDesc modelDesc;
List *colList = NIL;
- modelDesc = RelationGetDescr(modelRel);
+ modelDesc = RelationGetDescr(parent_rel);
for (parent_attno = 1; parent_attno <= modelDesc->natts;
parent_attno++)
@@ -22214,13 +22213,14 @@ getAttributesList(Relation modelRel)
/*
- * createTableConstraints: create constraints, default values and generated
- * values (prototype is function expandTableLikeClause).
- * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows.
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * moveMergedTablesRows.
*/
static void
createTableConstraints(List **wqueue, AlteredTableInfo *tab,
- Relation modelRel, Relation newRel)
+ Relation parent_rel, Relation newRel)
{
TupleDesc tupleDesc;
TupleConstr *constr;
@@ -22230,7 +22230,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
List *Constraints = NIL;
List *cookedConstraints = NIL;
- tupleDesc = RelationGetDescr(modelRel);
+ tupleDesc = RelationGetDescr(parent_rel);
constr = tupleDesc->constr;
if (!constr)
@@ -22265,13 +22265,13 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
NewColumnValue *newval;
if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
- this_default = build_generation_expression(modelRel, attribute->attnum);
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
else
{
this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
if (this_default == NULL)
elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
- attribute->attnum, RelationGetRelationName(modelRel));
+ attribute->attnum, RelationGetRelationName(parent_rel));
}
num = attmap->attnums[parent_attno - 1];
@@ -22288,14 +22288,14 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
errmsg("cannot convert whole-row table reference"),
errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
NameStr(attribute->attname),
- RelationGetRelationName(modelRel)));
+ RelationGetRelationName(parent_rel)));
/* Add a pre-cooked default expression. */
StoreAttrDefault(newRel, num, def, true);
/*
- * Stored generated column expressions in modelRel might reference
- * tableoid. newRel, modelRel tableoid clear is not the same. If
+ * Stored generated column expressions in parent_rel might reference
+ * tableoid. newRel, parent_rel tableoid clear is not the same. If
* so, these stored generated columns require recomputation for
* newRel within moveMergedTablesRows.
*/
@@ -22345,7 +22345,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
errmsg("cannot convert whole-row table reference"),
errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
ccname,
- RelationGetRelationName(modelRel)));
+ RelationGetRelationName(parent_rel)));
constr = makeNode(Constraint);
constr->contype = CONSTR_CHECK;
@@ -22370,7 +22370,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
CommandCounterIncrement();
/*
- * modelRel check constraint expresssion may reference tableoid, so later in
+ * parent_rel check constraint expresssion may reference tableoid, so later in
* moveMergedTablesRows, we need evulate the check constraint again for the
* newRel. We can check weather check constraint contain tableoid reference
* or not via pull_varattnos.
@@ -22386,8 +22386,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
pull_varattnos(qual, 1, &attnums);
/*
- * Add check only if it contains tableoid
- * (TableOidAttributeNumber).
+ * Add check only if it contains tableoid (TableOidAttributeNumber).
*/
if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
attnums))
@@ -22416,7 +22415,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
* The "include_noinh" argument is false because a partitioned table
* cannot have NO INHERIT constraint.
*/
- nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel),
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
false, false);
Assert(list_length(nnconstraints) > 0);
@@ -22431,20 +22430,18 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
/*
- * createPartitionTable: create table for a new partition with given name
- * (newPartName) like table (modelRel, partitioned table). ownerId is
- * determined by the partition on which the operation is performed, so it
- * is passed separately.
+ * createPartitionTable:
*
- * Also, this function sets the new partition access method same as parent
- * table access methods (similarly to CREATE TABLE ... PARTITION OF). It
- * checks that parent and child tables have compatible persistence.
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
*
- * Function returns the created relation (locked in AccessExclusiveLock mode).
+ * returns the created relation (locked in AccessExclusiveLock mode).
*/
static Relation
createPartitionTable(List **wqueue, RangeVar *newPartName,
- Relation modelRel, Oid ownerId)
+ Relation parent_rel, Oid ownerId)
{
Relation newRel;
Oid newRelId;
@@ -22456,19 +22453,19 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
AlteredTableInfo *new_partrel_tab;
/* If existing rel is temp, it must belong to this session */
- if (RELATION_IS_OTHER_TEMP(modelRel))
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create as partition of temporary relation of another session"));
/* Look up inheritance ancestors and generate relation schema. */
- colList = getAttributesList(modelRel);
+ colList = getAttributesList(parent_rel);
/* Create a tuple descriptor from the relation schema. */
descriptor = BuildDescForRelation(colList);
/* Look up the access method for new relation. */
- relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID;
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
/* Look up the namespace in which we are supposed to create the relation. */
namespaceId =
@@ -22481,7 +22478,7 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
/* Create the relation. */
newRelId = heap_create_with_catalog(newPartName->relname,
namespaceId,
- modelRel->rd_rel->reltablespace,
+ parent_rel->rd_rel->reltablespace,
InvalidOid,
InvalidOid,
InvalidOid,
@@ -22497,7 +22494,7 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
(Datum) 0,
true,
allowSystemTableMods,
- false,
+ true,
InvalidOid,
NULL);
@@ -22522,23 +22519,23 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
* affected by the search_path. If the parent is permanent, so must be
* all of its partitions.
*/
- if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
- RelationGetRelationName(modelRel)));
+ RelationGetRelationName(parent_rel)));
/* Permanent rels cannot be partitions belonging to temporary parent */
if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
- modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
- RelationGetRelationName(modelRel)));
+ RelationGetRelationName(parent_rel)));
/* Create constraints, default values and generated values */
- createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel);
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
/*
* Need to call CommandCounterIncrement, so fresh relcache entry have newly
@@ -22831,9 +22828,19 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
defaultPartOid =
get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
/*
- * Detach all merged partitions.
- *
* Perform a preliminary check to determine whether it's safe to drop all
* merging partitions before we actually do so later. After merging rows
* into the new partitions via moveMergedTablesRows, all old partitions need
@@ -22841,17 +22848,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* merge process (moveMergedTablesRows) can be time-consuming, performing an
* early check on the drop eligibility of old partitions is preferable.
*/
- foreach_oid(mergingPartitionOid, mergingPartitions)
- {
- Relation child_rel;
-
- child_rel = table_open(mergingPartitionOid, NoLock);
-
- detachPartitionTable(rel, child_rel, defaultPartOid);
-
- table_close(child_rel, NoLock);
- }
-
foreach_oid(mergingPartitionOid, mergingPartitions)
{
ObjectAddress object;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index f5e6ec6184a..531f2021aad 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -48,6 +48,12 @@ LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
--ERROR, sales_apr_2 already exists
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
-- NO ERROR: test for custom partitions order, source partitions not in the search_path
SET search_path = partitions_merge_schema2, public;
ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
@@ -587,49 +593,25 @@ EXECUTE get_partition_info('{sales_list}');
sales_others | p | r | f | DEFAULT
(3 rows)
-SELECT * FROM sales_list;
- salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
-----------------+------------------+----------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
(14 rows)
-SELECT * FROM sales_nord;
- salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
-----------------+------------------+----------------+--------------+------------
- 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- 7 | May | Helsinki | 1200 | 03-06-2022
- 9 | May | Helsinki | 1200 | 03-11-2022
- 10 | Halder | Oslo | 800 | 03-02-2022
-(4 rows)
-
-SELECT * FROM sales_all;
- salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
-----------------+------------------+-------------+--------------+------------
- 2 | Smirnoff | New York | 500 | 03-03-2022
- 5 | Deev | Lisbon | 250 | 03-07-2022
- 11 | Muller | Madrid | 650 | 03-05-2022
- 14 | Plato | Lisbon | 950 | 03-05-2022
- 1 | Trump | Bejing | 1000 | 03-01-2022
- 8 | Li | Vladivostok | 1150 | 03-09-2022
- 4 | Ivanov | Warsaw | 750 | 03-04-2022
- 6 | Poirot | Berlin | 1000 | 03-01-2022
- 12 | Smith | Kyiv | 350 | 03-10-2022
- 13 | Gandi | Warsaw | 150 | 03-08-2022
-(10 rows)
-
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index 2cdd58b2008..bf8acc5136c 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -42,6 +42,10 @@ ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitio
--ERROR, sales_apr_2 already exists
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
-- NO ERROR: test for custom partitions order, source partitions not in the search_path
SET search_path = partitions_merge_schema2, public;
ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
@@ -414,9 +418,7 @@ ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
-- show partitions with conditions:
EXECUTE get_partition_info('{sales_list}');
-SELECT * FROM sales_list;
-SELECT * FROM sales_nord;
-SELECT * FROM sales_all;
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
--
2.34.1
Hi!
1.
v47-0001-rename-function-argument-and-minor-refactor.no-cfbot
Thanks, applied.
2.
+ * Construct a map from the LIKE relation's attnos to the child rel's
this comment in createTableConstraints is confusing, especially the
word "LIKE". I didn' change it though.
It is copy from expandTableLikeClause function. Changed.
3.
the argument (Relation rel) never used in moveMergedTablesRows
we can remove it, or rename it as "parent_rel".
I didn' change it though.
Removed.
4.
moveMergedTablesRows was never used in SPLIT PARTITION,
so maybe we can rename it to
ATMergePartitionMoveTablesRows
or
ATMergePartitionMoveRows
or
ATMergePartitionRows
what do you think?
I like the name "MergePartitionsMoveRows" (without prefix "AT" - "ALTER
TABLE", because this function is not called from ATExecCmd function).
Is it ok?
5.
so I added a test for it. as you can see below, the error HINT message
is not great in this context.
...
HINT: Use DROP ... CASCADE to drop the dependent objects too.
Maybe a special flag (DEPFLAG_NOHINT?) should be added to skip hints for
the performDeletionCheck function?
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v48-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v48-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From a52039cdba5fd788747cfacf6037a103d5424881 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v48 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 104 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 908 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 148 +++
src/backend/partitioning/partbounds.c | 199 ++-
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1105 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 796 ++++++++++++
21 files changed, 3612 insertions(+), 28 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..e503a06028 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1150,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1487,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1921,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968..5afc493820 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 10f43c51c5..696f80be83 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index ea96947d81..7f63df0612 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,840 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might reference
+ * tableoid. newRel, parent_rel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need evulate the check constraint again
+ * for the newRel. We can check weather check constraint contain tableoid
+ * reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..f55ad17528 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3900,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 contain 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 4bdc2941ef..9f7c01b7fa 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent,
PartitionRangeDatum *datum;
/*
- * Point to problematic key in the lower datums list;
- * if we have equality, point to the first one.
+ * Point to problematic key in the list of lower
+ * datums; if we have equality, point to the first
+ * one.
*/
datum = cmpval == 0 ? linitial(spec->lowerdatums) :
list_nth(spec->lowerdatums, abs(cmpval) - 1);
@@ -4977,3 +4978,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2c0b4f28c1..64248b5b1f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..531f2021aa
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1105 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bf8acc5136
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,796 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v48-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v48-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 7f8efea72095bfab3bc8bd039c6e345b22495a87 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v48 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 92 +-
src/backend/commands/tablecmds.c | 465 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 65 +-
src/backend/partitioning/partbounds.c | 684 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1655 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1148 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4446 insertions(+), 23 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index e503a06028..daadb8326b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...])
INTO <replaceable class="parameter">partition_name</replaceable>
@@ -1150,6 +1154,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1244,7 +1313,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1488,7 +1558,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1921,6 +1991,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7f63df0612..d3edfce184 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22909,3 +22931,446 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via SplitPartitionMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index f55ad17528..73315efac8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,46 @@ checkPartition(Relation rel, Oid partRelOid)
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3892,7 +3932,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3900,6 +3940,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3908,7 +3949,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4343,13 +4388,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4358,9 +4403,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4368,7 +4413,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 9f7c01b7fa..9c730e127c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4984,15 +4984,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5001,6 +5007,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,7 +5029,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5134,7 +5141,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5172,3 +5179,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 64248b5b1f..c0e918951a 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7d543ab813
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1655 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..7fa4b69376
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1148 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 32d6e718ad..b815cced84 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2766,6 +2766,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2832,6 +2833,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
here, we don't need ``(void *)``
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable
class="parameter">partition_name1</replaceable>, <replaceable
class="parameter">partition_name2</replaceable> [, ...])
+ INTO <replaceable class="parameter">partition_name</replaceable>
In the synopsis section, we can combine the last two lines into one
for better formatting.
after
<varlistentry id="sql-altertable-parms-partition-name">
we can add the following to briefly explain parameters: partition_name1,
partition_name2
<varlistentry id="sql-altertable-parms-partition-name1">
<term><replaceable class="parameter">partition_name1</replaceable></term>
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
What do you think about alternative syntax:
ALTER TABLE tab1 MERGE PARTITION part1 WITH (part2, part3) mentioned in [1]/messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com.
I think we need to settle this issue before moving forward.
If the current MERGE PARTITION design is finalized, then v48-0001 looks solid.
[1]: /messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
Hi!
Thanks for notes!
1.
here, we don't need ``(void *)``
Corrected.
2.
In the synopsis section, we can combine the last two lines into one
for better formatting.
Changed.
3.
after ...
we can add the following to briefly explain parameters: partition_name1,
partition_name2
Added.
4.
What do you think about alternative syntax:
ALTER TABLE tab1 MERGE PARTITION part1 WITH (part2, part3) mentioned
in [1]/messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com.
....
Is it additional syntax (to the existing one) with functionality:
partition part1 survives and data from partitions part2, part3 is moved
into part1?
And (if "yes") should we delete the part1 indexes (or other constraints)
before moving the data?
[1]: /messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
/messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v49-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v49-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From d5f7f509b97485970e970e3d5b1f9fba228f962c Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v49 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 113 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 908 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 148 +++
src/backend/partitioning/partbounds.c | 194 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1105 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 796 ++++++++++++
21 files changed, 3618 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 96936bcd3a..62c2bb54ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d63f3a621a..dd429c12b1 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1149,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1486,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1930,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 18316a3968..5afc493820 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 10f43c51c5..696f80be83 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 074ddb6b9c..34858ab509 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5269,6 +5275,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5665,6 +5676,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);
@@ -6705,6 +6724,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:
@@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20372,23 +20424,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22035,3 +22072,840 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might reference
+ * tableoid. newRel, parent_rel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need evulate the check constraint again
+ * for the newRel. We can check weather check constraint contain tableoid
+ * reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 50f53159d5..46bbdcbc74 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2331,6 +2331,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2345,6 +2346,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2358,6 +2360,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2374,6 +2391,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17876,6 +17894,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18503,6 +18522,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 62015431fd..f55ad17528 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3488,6 +3491,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3765,6 +3900,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 contain 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 4bdc2941ef..ea33c15194 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 908eef97c6..1145b9d7ce 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ba12678d1c..b8e2a679cd 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..531f2021aa
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1105 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bf8acc5136
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,796 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v49-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v49-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From f8a40867cf3d03899722cab3716d7374e69c65e9 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v49 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 95 +-
src/backend/commands/tablecmds.c | 465 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 65 +-
src/backend/partitioning/partbounds.c | 684 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1655 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1148 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4448 insertions(+), 24 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 62c2bb54ea..41e477eddf 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4461,6 +4461,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index dd429c12b1..7b143c6585 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1149,6 +1153,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1243,7 +1312,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1487,7 +1557,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1497,7 +1567,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1930,6 +2001,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 34858ab509..de73540334 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5280,6 +5287,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5684,6 +5696,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6726,6 +6746,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22909,3 +22931,446 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via SplitPartitionMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 46bbdcbc74..aed79b63da 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2321,6 +2324,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2365,6 +2385,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -17963,6 +17997,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18603,6 +18638,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index f55ad17528..73315efac8 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3526,6 +3526,46 @@ checkPartition(Relation rel, Oid partRelOid)
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3892,7 +3932,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3900,6 +3940,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
newcmds = lappend(newcmds, cmd);
break;
+ case AT_SplitPartition:
case AT_MergePartitions:
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
@@ -3908,7 +3949,11 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two items"));
- transformPartitionCmdForMerge(&cxt, partcmd);
+
+ if (cmd->subtype == AT_SplitPartition)
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ else
+ transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
}
@@ -4343,13 +4388,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4358,9 +4403,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4368,7 +4413,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index ea33c15194..e1c1416b1e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4983,15 +4983,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5000,6 +5006,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5021,7 +5028,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5133,7 +5140,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5171,3 +5178,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 1145b9d7ce..e4d3c5c940 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2721,7 +2721,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -2977,10 +2977,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -2988,6 +2988,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b8e2a679cd..01aa4b2e64 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7d543ab813
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1655 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two items
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two items
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..7fa4b69376
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1148 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two items
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 32d6e718ad..b815cced84 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2766,6 +2766,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2832,6 +2833,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Wed, Jun 25, 2025 at 5:28 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Thanks for notes!
hi.
+static void
+transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+
+ /* Is current partition a DEFAULT partition? */
+ defaultPartOid =
get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
this comment seems wrong?
it should be "does this partitioned table (parent) have a default partition?
+ 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 contain at least two items"));
This error message is not good, IMHO. I don't really have any good ideas though.
if we polish this message later, now we can add a comment: "FIXME
improve this error message".
in ATExecMergePartitions we have:
RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
it will call RangeVarAdjustRelationPersistence
after it, the cmd->name->relpersistence will be set properly.
so the following in createPartitionTable can be checked way earlier.
/*
* We intended to create the partition with the same persistence as the
* parent table, but we still need to recheck because that might be
* affected by the search_path. If the parent is permanent, so must be
* all of its partitions.
*/
if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create a temporary relation as
partition of permanent relation \"%s\"",
RelationGetRelationName(parent_rel)));
/* Permanent rels cannot be partitions belonging to temporary parent */
if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot create a permanent relation as
partition of temporary relation \"%s\"",
RelationGetRelationName(parent_rel)));
after createPartitionTable->heap_create_with_catalog do the error check seems
unintuitive to me.
it can be checked right after RangeVarGetAndCheckCreationNamespace.
Hi!
1.
this comment seems wrong?
it should be "does this partitioned table (parent) have a default
partition?
Agreed, this comment belongs to different code position. Corrected.
2.
This error message is not good, IMHO. I don't really have any good
ideas though.
if we polish this message later, now we can add a comment: "FIXME
improve this error message".
Probably it won't be possible to make the error message correct for both
MERGE PARTITIONS and SPLIT PARTITION.
I split code for MERGE PARTITIONS and SPLIT PARTITION and now error
messages are different for them.
3.
after createPartitionTable->heap_create_with_catalog do the error check
seems unintuitive to me.
it can be checked right after RangeVarGetAndCheckCreationNamespace.
I agree that these error checks are unintuitive.
But the createPartitionTable function, which contains checks, will be
used in many places - not only for MERGE PARTITIONS, but also for SPLIT
PARTITION. I think it's not a good idea to do the same checks in
different places in code. Maybe it's better to do these checks in one
place (even though it's unintuitive)?
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v50-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v50-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 72a58e0b4cf97baa2e0d4721724f52e57c6d538b Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v50 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 113 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 908 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 149 +++
src/backend/partitioning/partbounds.c | 194 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1105 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 796 ++++++++++++
21 files changed, 3619 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 1e4f26c13f..c8f784bcbc 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1149,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1486,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1930,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..3dd81188f7 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fd6537567e..7514eab4cd 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index cb811520c2..50fd7fc905 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4833,6 +4835,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5268,6 +5274,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5664,6 +5675,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);
@@ -6704,6 +6723,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:
@@ -20193,6 +20214,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20394,23 +20446,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22057,3 +22094,840 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might reference
+ * tableoid. newRel, parent_rel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need evulate the check constraint again
+ * for the newRel. We can check weather check constraint contain tableoid
+ * reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 73345bb3c7..7656eadf1f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2338,6 +2338,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2352,6 +2353,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2365,6 +2367,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2381,6 +2398,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17941,6 +17959,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18568,6 +18587,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index afcf54169c..8fe7249203 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3510,6 +3513,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3787,6 +3922,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 4bdc2941ef..ea33c15194 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6872653c6c..2f263d106b 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2742,6 +2742,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3015,6 +3016,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..7c607dc55a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..5159fd37d8
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1105 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bb5386fe38
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,796 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v50-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v50-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From eedda380f00b36ac0067fe013161a963072c52e2 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v50 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 95 +-
src/backend/commands/tablecmds.c | 465 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 72 +-
src/backend/partitioning/partbounds.c | 684 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 16 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1655 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1148 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4456 insertions(+), 23 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index c8f784bcbc..660e67f718 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1149,6 +1153,71 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions or one of existing partitions is
+ <literal>DEFAULT</literal>, new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition and the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1243,7 +1312,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1487,7 +1557,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1497,7 +1567,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1930,6 +2001,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 50fd7fc905..9ce36b0664 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5279,6 +5286,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5683,6 +5695,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6725,6 +6745,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22931,3 +22953,446 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures.
+ * newPartRels: list of Relations.
+ * defaultPartOid: oid of DEFAULT partition, for table rel.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels, Oid defaultPartOid)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+ bool isOldDefaultPart = false;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ /*
+ * Create partition context for DEFAULT partition. We can insert values
+ * into this partition in case spaces with values between new partitions.
+ */
+ if (!defaultPartCtx && OidIsValid(defaultPartOid))
+ {
+ /* Indicate that we allocate context for old DEFAULT partition */
+ isOldDefaultPart = true;
+ defaultPartCtx = createSplitPartitionContext(table_open(defaultPartOid, AccessExclusiveLock));
+
+ /* Find the work queue entry for default partition table. */
+ defaultPartCtx->tab = ATGetQueueEntry(wqueue, defaultPartCtx->partRel);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+
+ /* Need to close table and free buffers for DEFAULT partition. */
+ if (isOldDefaultPart)
+ {
+ Relation defaultPartRel = defaultPartCtx->partRel;
+
+ deleteSplitPartitionContext(defaultPartCtx, wqueue, ti_options);
+ /* Keep the lock until commit. */
+ table_close(defaultPartRel, NoLock);
+ }
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via SplitPartitionMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels, defaultPartOid);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7656eadf1f..332dcb5e4a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2328,6 +2331,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2372,6 +2392,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18028,6 +18062,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18668,6 +18703,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 8fe7249203..bd045c154d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3548,6 +3548,46 @@ checkPartition(Relation rel, Oid partRelOid)
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3914,7 +3954,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3936,6 +3976,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4366,13 +4420,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4381,9 +4435,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4391,7 +4445,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index ea33c15194..e1c1416b1e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4983,15 +4983,21 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 determining error position
*/
static void
@@ -5000,6 +5006,7 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5021,7 +5028,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5133,7 +5140,7 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- pstate);
+ false, pstate);
}
/*
@@ -5171,3 +5178,672 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case partitioned table has DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool existsDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that partitioned table has (or will have) DEFAULT partition */
+ existsDefaultPart = OidIsValid(defaultPartOid) || (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ existsDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound, existsDefaultPart, pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!existsDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 2f263d106b..34c25db5a6 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2742,7 +2742,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3005,10 +3005,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3016,6 +3016,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 7c607dc55a..6bd70dbfe4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,15 +963,26 @@ typedef struct PartitionRangeDatum
ParseLoc 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
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2486,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..3a8a5c41f3
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1655 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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;
+ salesperson_id | salesperson_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_feb2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM partition_split_schema2.sales_mar2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_range;
+ salesperson_id | salesperson_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_apr2022;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6466a4f978
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1148 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is less than lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is greater than upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_jan2022;
+SELECT * FROM sales_feb2022;
+SELECT * FROM partition_split_schema2.sales_mar2022;
+SELECT * FROM sales_apr2022;
+SELECT * FROM sales_others;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_range;
+SELECT * FROM sales_apr2022;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ff050e93a5..6955668aef 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2772,6 +2772,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2838,6 +2839,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
bug:
begin;
drop table if exists pks cascade;
create table pks(i int primary key, b int) partition by range (i);
create table pks_34 partition of pks for values from (3) to (6);
create table pks_d partition of pks default;
insert into pks values (0), (1), (3), (4), (5);
commit;
alter table pks_d add constraint cc check(i <> 5);
ALTER TABLE pks SPLIT PARTITION pks_34 INTO
(PARTITION pks_3 FOR VALUES FROM (3) TO (4),
PARTITION pks_4 FOR VALUES FROM (4) TO (5));
now pks_d have values(5) for column i, which would violate the
cc check constraint.
------------------------
/*
* PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
*/
typedef struct PartitionCmd
{
NodeTag type;
RangeVar *name; /* name of partition to
attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
"ALTER TABLE/INDEX ATTACH/DETACH PARTITION" comments need updated.
SplitPartitionMoveRows
ereport(ERROR,
errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split
partition row"),
errtable(splitRel));
will this ever be reachable?
in SplitPartitionMoveRows
+ if (sps->bound->is_default)
+ {
+ /* We should not create constraint for detached DEFAULT partition. */
+ defaultPartCtx = pc;
+ }
I am not sure the comment "detached DEFAULT partition" is correct.
the "constraint" is not ideal, better word would be "partition
constraint" or "partition qual".
In ATExecSplitPartition,
we can first create the new partitions and then detach the original partition.
It makes more sense, IMHO.
For example:
ALTER TABLE pks SPLIT PARTITION pks_34 INTO
(PARTITION pks_3 FOR VALUES FROM (3) TO (4),
PARTITION pks_4 FOR VALUES FROM (4) TO (6));
In this case, we could first create the relations pks_3 and pks_4, then detach
the partition pks_34
should the newly created partitions be based on the split partition or on the
partitioned table?
In the current v50 implementation, they are based on the partitioned table, but
these newly created partitions based on the split partition also make sense.
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ if (pc->partqualstate /* skip DEFAULT partition */ &&
+ ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ ResetExprContext(econtext);
this ResetExprContext is not needed, if you are evaluate different
ExprState again the same slot. See ExecRelCheck also.
see execute_extension_script
control->trusted
? errhint("Must have CREATE privilege on current
database to create this extension.")
: errhint("Must be superuser to create this extension.")));
in v50-0002, we can refactor it as like the following
checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
partRel = table_open(partRelOid, NoLock);
if (partRel->rd_rel->relkind != RELKIND_RELATION)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table",
RelationGetRelationName(partRel)),
is_merge
? errhint("ALTER TABLE ... MERGE PARTITIONS can only
merge partitions don't have sub-partitions")
: errhint("ALTER TABLE ... SPLIT PARTITIONS can only
split partitions don't have sub-partitions"));
I did some regress test refactoring to reduce test size.
-SELECT * FROM sales_range;
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
other miscellaneous refactoring is also attached.
Attachments:
fix-v50-0002-nocfbotapplication/octet-stream; name=fix-v50-0002-nocfbotDownload
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9ce36b06643..0c594655a8c 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -23024,8 +23024,10 @@ deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_opt
* (rel) and move rows into new partitions.
*
* New partitions description:
- * partlist: list of pointers to SinglePartitionSpec structures.
- * newPartRels: list of Relations.
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
* defaultPartOid: oid of DEFAULT partition, for table rel.
*/
static void
@@ -23149,13 +23151,12 @@ SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
{
pc = (SplitPartitionContext *) lfirst(listptr);
- if (pc->partqualstate /* skip DEFAULT partition */ &&
- ExecCheck(pc->partqualstate, econtext))
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
{
found = true;
break;
}
- ResetExprContext(econtext);
}
if (!found)
{
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index bd045c154de..870712577ba 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3517,9 +3517,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
* Partition with OID partRelOid must be locked before function call.
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3529,21 +3531,27 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
@@ -3581,7 +3589,7 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
RangeVarCallbackOwnsRelation,
NULL);
- checkPartition(parent, splitPartOid);
+ checkPartition(parent, splitPartOid, false);
/* Then we should check partitions with transformed bounds. */
check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
@@ -3666,7 +3674,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index e1c1416b1ec..a2b5f23cea0 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4998,6 +4998,8 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* second_name: name of second partition
* second_bound: bound of second partition
* defaultPart: true if one of split partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5007,6 +5009,7 @@ check_two_partitions_bounds_range(Relation parent,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5036,7 +5039,9 @@ check_two_partitions_bounds_range(Relation parent,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5140,7 +5145,9 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
- false, pstate);
+ false,
+ true,
+ pstate);
}
/*
@@ -5813,7 +5820,10 @@ check_partitions_for_split(Relation parent,
/* Ranges of new partitions should not overlap. */
if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
- sps->name, sps->bound, existsDefaultPart, pstate);
+ sps->name, sps->bound,
+ existsDefaultPart,
+ false,
+ pstate);
spsPrev = sps;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 3a8a5c41f31..b1844263524 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -96,7 +96,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
-- Tests for spaces between partitions, them should be executed without DEFAULT partition
ALTER TABLE sales_range DETACH PARTITION sales_others;
-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
@@ -157,64 +157,25 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-SELECT * FROM sales_range;
- salesperson_id | salesperson_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
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+----------+----------------+------------------+--------------+------------
+ 19614 | 1 | May | 1000 | 01-31-2022
+ 19623 | 2 | Smirnoff | 500 | 02-10-2022
+ 19629 | 3 | Ford | 2000 | 04-30-2022
+ 19629 | 4 | Ivanov | 750 | 04-13-2022
+ 19629 | 5 | Deev | 250 | 04-07-2022
+ 19623 | 6 | Poirot | 150 | 02-11-2022
+ 19626 | 7 | Li | 175 | 03-08-2022
+ 19623 | 8 | Ericsson | 185 | 02-23-2022
+ 19626 | 9 | Muller | 250 | 03-11-2022
+ 19614 | 10 | Halder | 350 | 01-28-2022
+ 19629 | 11 | Trump | 380 | 04-06-2022
+ 19626 | 12 | Plato | 350 | 03-19-2022
+ 19614 | 13 | Gandi | 377 | 01-09-2022
+ 19620 | 14 | Smith | 510 | 05-04-2022
(14 rows)
-SELECT * FROM sales_jan2022;
- salesperson_id | salesperson_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_feb2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 2 | Smirnoff | 500 | 02-10-2022
- 6 | Poirot | 150 | 02-11-2022
- 8 | Ericsson | 185 | 02-23-2022
-(3 rows)
-
-SELECT * FROM sales_mar2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
-(3 rows)
-
-SELECT * FROM sales_apr2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
-(4 rows)
-
-SELECT * FROM sales_others;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
-(1 row)
-
DROP TABLE sales_range CASCADE;
--
-- Add split partition, then add rows into partitioned table
@@ -258,64 +219,25 @@ INSERT INTO sales_range VALUES
(12, 'Plato', 350, '2022-03-19'),
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT * FROM sales_range;
- salesperson_id | salesperson_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
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+----------+----------------+------------------+--------------+------------
+ 19635 | 1 | May | 1000 | 01-31-2022
+ 19644 | 2 | Smirnoff | 500 | 02-10-2022
+ 19650 | 3 | Ford | 2000 | 04-30-2022
+ 19650 | 4 | Ivanov | 750 | 04-13-2022
+ 19650 | 5 | Deev | 250 | 04-07-2022
+ 19644 | 6 | Poirot | 150 | 02-11-2022
+ 19647 | 7 | Li | 175 | 03-08-2022
+ 19644 | 8 | Ericsson | 185 | 02-23-2022
+ 19647 | 9 | Muller | 250 | 03-11-2022
+ 19635 | 10 | Halder | 350 | 01-28-2022
+ 19650 | 11 | Trump | 380 | 04-06-2022
+ 19647 | 12 | Plato | 350 | 03-19-2022
+ 19635 | 13 | Gandi | 377 | 01-09-2022
+ 19641 | 14 | Smith | 510 | 05-04-2022
(14 rows)
-SELECT * FROM sales_jan2022;
- salesperson_id | salesperson_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_feb2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 2 | Smirnoff | 500 | 02-10-2022
- 6 | Poirot | 150 | 02-11-2022
- 8 | Ericsson | 185 | 02-23-2022
-(3 rows)
-
-SELECT * FROM partition_split_schema2.sales_mar2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 7 | Li | 175 | 03-08-2022
- 9 | Muller | 250 | 03-11-2022
- 12 | Plato | 350 | 03-19-2022
-(3 rows)
-
-SELECT * FROM sales_apr2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
-(4 rows)
-
-SELECT * FROM sales_others;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 14 | Smith | 510 | 05-04-2022
-(1 row)
-
DROP TABLE sales_range CASCADE;
--
-- Test for:
@@ -508,7 +430,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
-- sales_error intersects with sales_feb2022 (upper bound)
-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -519,7 +441,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
-- sales_error intersects with sales_dec2021 (inside bound)
-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -530,7 +452,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
-- sales_error intersects with sales_dec2021 (exactly the same bounds)
-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
@@ -541,7 +463,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
@@ -873,34 +795,25 @@ INSERT INTO sales_range VALUES
(12, 'Plato', 350, '2022-03-19'),
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT * FROM sales_range;
- salesperson_id | salesperson_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
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+----------+----------------+------------------+--------------+------------
+ 19985 | 1 | May | 1000 | 01-31-2022
+ 19988 | 2 | Smirnoff | 500 | 02-10-2022
+ 19997 | 3 | Ford | 2000 | 04-30-2022
+ 19997 | 4 | Ivanov | 750 | 04-13-2022
+ 19997 | 5 | Deev | 250 | 04-07-2022
+ 19988 | 6 | Poirot | 150 | 02-11-2022
+ 19991 | 7 | Li | 175 | 03-08-2022
+ 19988 | 8 | Ericsson | 185 | 02-23-2022
+ 19991 | 9 | Muller | 250 | 03-11-2022
+ 19985 | 10 | Halder | 350 | 01-28-2022
+ 19997 | 11 | Trump | 380 | 04-06-2022
+ 19991 | 12 | Plato | 350 | 03-19-2022
+ 19985 | 13 | Gandi | 377 | 01-09-2022
+ 20000 | 14 | Smith | 510 | 05-04-2022
(14 rows)
-SELECT * FROM sales_apr2022;
- salesperson_id | salesperson_name | sales_amount | sales_date
-----------------+------------------+--------------+------------
- 3 | Ford | 2000 | 04-30-2022
- 4 | Ivanov | 750 | 04-13-2022
- 5 | Deev | 250 | 04-07-2022
- 11 | Trump | 380 | 04-06-2022
-(4 rows)
-
ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
(PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
@@ -1252,7 +1165,7 @@ ALTER TABLE t2 SPLIT PARTITION t1pa INTO
(PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
ERROR: relation "t1pa" is not a partition of relation "t2"
-HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
DROP TABLE t2;
DROP TABLE t1;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 6466a4f978e..a718b44f686 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -135,13 +135,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-SELECT * FROM sales_range;
-SELECT * FROM sales_jan2022;
-SELECT * FROM sales_feb2022;
-SELECT * FROM sales_mar2022;
-SELECT * FROM sales_apr2022;
-SELECT * FROM sales_others;
-
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
DROP TABLE sales_range CASCADE;
--
@@ -175,12 +169,7 @@ INSERT INTO sales_range VALUES
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT * FROM sales_range;
-SELECT * FROM sales_jan2022;
-SELECT * FROM sales_feb2022;
-SELECT * FROM partition_split_schema2.sales_mar2022;
-SELECT * FROM sales_apr2022;
-SELECT * FROM sales_others;
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
DROP TABLE sales_range CASCADE;
@@ -575,8 +564,7 @@ INSERT INTO sales_range VALUES
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT * FROM sales_range;
-SELECT * FROM sales_apr2022;
+SELECT tableoid, * FROM sales_range ORDER BY salesperson_id;
ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
(PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
Hi!
1.
bug:
...
now pks_d have values(5) for column i, which would violate the
cc check constraint.
Probably we shouldn't use a DEFAULT-partition if it wasn't created by
SPLIT PARTITION command, because DEFAULT-partition can has other
restrictions besides CHECK (e.g. FOREIGN KEY).
Corrected.
2.
"ALTER TABLE/INDEX ATTACH/DETACH PARTITION" comments need updated.
Updated.
3.
SplitPartitionMoveRows
ereport(ERROR,
errcode(ERRCODE_CHECK_VIOLATION),
errmsg("can not find partition for split partition row"),
errtable(splitRel));
will this ever be reachable?
In case correct work, there should be no errors. This is insurance.
4.
I am not sure the comment "detached DEFAULT partition" is correct.
the "constraint" is not ideal, better word would be "partition
constraint" or "partition qual".
Corrected.
5.
In this case, we could first create the relations pks_3 and pks_4,
then detach the partition pks_34
I think it's better not to change the code, because detachPartitionTable
function call should be before performDeletionCheck.
And performDeletionCheck function should be used as soon as possible.
6.
should the newly created partitions be based on the split partition
or on the partitioned table?
In the current v50 implementation, they are based on the partitioned
table, but these newly created partitions based on the split partition
also make sense.
Yes, now newly created partitions are based on the partitioned.
I think this is more correct: user after SPLIT can modify some of new
partitions as he wants.
7.
this ResetExprContext is not needed, if you are evaluate different
ExprState again the same slot. See ExecRelCheck also.
Thanks!
8.
I did some regress test refactoring to reduce test size.
other miscellaneous refactoring is also attached.
Thanks!
P.S. Excuse me, but I can't answer emails for the next three weeks.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v51-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v51-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 7057641bd4604634160e8c474f3cac4020057cdd Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v51 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 113 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 908 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 149 +++
src/backend/partitioning/partbounds.c | 194 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1105 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 796 ++++++++++++
21 files changed, 3619 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 1e4f26c13f..c8f784bcbc 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1147,14 +1149,101 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1397,7 +1486,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1830,6 +1930,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..3dd81188f7 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object plus
+ * everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fd6537567e..7514eab4cd 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 2d5ac1ea81..1f948876d9 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index cb811520c2..50fd7fc905 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4833,6 +4835,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5268,6 +5274,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5664,6 +5675,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);
@@ -6704,6 +6723,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:
@@ -20193,6 +20214,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20394,23 +20446,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22057,3 +22094,840 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might reference
+ * tableoid. newRel, parent_rel tableoid clear is not the same. If
+ * so, these stored generated columns require recomputation for
+ * newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need evulate the check constraint again
+ * for the newRel. We can check weather check constraint contain tableoid
+ * reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have newly
+ * installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired
+ * value. (We must do this each time, because it gets
+ * overwritten with newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in here,
+ * so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 73345bb3c7..7656eadf1f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2338,6 +2338,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2352,6 +2353,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2365,6 +2367,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2381,6 +2398,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17941,6 +17959,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18568,6 +18587,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index afcf54169c..8fe7249203 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3510,6 +3513,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions before
+ * calculating the boundary for resulting partition, we also check for
+ * ownership along the way. We need to use AccessExclusiveLock here,
+ * because these merged partitions will be detached then dropped in
+ * ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3787,6 +3922,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 4bdc2941ef..ea33c15194 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4977,3 +4977,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3752436429..89116b177b 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2742,6 +2742,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3015,6 +3016,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..7c607dc55a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..5159fd37d8
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1105 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a424be2a6b..6464a238ac 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bb5386fe38
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,796 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v51-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v51-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 5eaae5c7f14afe72ee2613d07c6dcb5031cf9f13 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v51 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 94 +-
src/backend/commands/tablecmds.c | 442 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 90 +-
src/backend/partitioning/partbounds.c | 694 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 19 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1566 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1135 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4355 insertions(+), 29 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index c8f784bcbc..31ae93113b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1149,6 +1153,70 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1243,7 +1311,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1487,7 +1556,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1497,7 +1566,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1930,6 +2000,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 50fd7fc905..8bf0ec1b43 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5279,6 +5286,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5683,6 +5695,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6725,6 +6745,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22931,3 +22953,423 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID during
+ * storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop split
+ * partition before we actually do so later. After merging rows into the new
+ * partitions via SplitPartitionMoveRows, all old partitions need be
+ * dropped. However, since the drop behavior is DROP_RESTRICT and the merge
+ * process (SplitPartitionMoveRows) can be time-consuming, performing an
+ * early check on the drop eligibility of old partitions is preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7656eadf1f..332dcb5e4a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2328,6 +2331,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2372,6 +2392,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18028,6 +18062,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18668,6 +18703,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 8fe7249203..870712577b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3517,9 +3517,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
* Partition with OID partRelOid must be locked before function call.
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3529,25 +3531,71 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3626,7 +3674,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3914,7 +3962,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3936,6 +3984,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4366,13 +4428,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4381,9 +4443,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4391,7 +4453,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index ea33c15194..2b03bfc223 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4983,15 +4983,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5000,6 +5008,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5021,7 +5031,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5029,7 +5039,9 @@ check_two_partitions_bounds_range(Relation parent,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5133,6 +5145,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5171,3 +5185,675 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+
+ if (equal(sps->name, sps2->name))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 89116b177b..b219155ea2 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2742,7 +2742,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3005,10 +3005,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3016,6 +3016,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 7c607dc55a..ef9032744a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,14 +964,26 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * 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 and for
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE
+ List *partlist; /* list of partitions, for MERGE/SPLIT
* PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2487,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..dfbc59167b
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1566 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6464a238ac..a98aef7ca1 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6853a25537
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1135 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ff050e93a5..6955668aef 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2772,6 +2772,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2838,6 +2839,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi, Dmitry!
I went through the patches. Both of them applied with a small conflict in
the parallel_schedule, which is easy to resolve.
+ 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);
Similar fragments are present in SplitPartitionMoveRows()
and MergePartitionsMoveRows(). Do you think we could use ExecCopySlot()
(or similar) instead?
The presence of the same name in the split partition list is checked with
equal() (similar concern was already raised about the merge case [1]). If
one of the names is schema-qualified, the error message is different.
Could we make them the same?
# alter table part_test split partition part_test_1_2 into (partition
part_test_1 for values in (1), partition part_test_1 for values in (2));
ERROR: name "part_test_1" is already used
LINE 1: ...artition part_test_1 for values in (1), partition part_test_...
^
Time: 1.194 ms
# alter table part_test split partition part_test_1_2 into (partition
part_test_1 for values in (1), partition public.part_test_1 for values in
(2));
ERROR: relation "part_test_1" already exists
Time: 6.187 ms
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
I see we're searching for a partition to place each row using the
sequential application of partition constraints. I concerned if this could
be exhausting when the number of new partitions is large. Could we use
something like binary search here?
New split/drop commands do the full reorganization of the involved
partitions. As Robert previously stated [2], there are other possible
strategies. While they are hard to implement, I don't think we need them
in the initial version. But I think it's worth mentioning in the docs that
we're completely rewriting the involved partitions. And this is not
recommended to use for merging very big partitions with small ones, and
splitting a small fraction of rows out of a very big partition.
Both patches could use pgindent run.
Links
1.
/messages/by-id/CACJufxHHnJm6Jb2YQpuRU1RX__tO=JJNJ5=EUMuzif_KNxGd9A@mail.gmail.com
2.
/messages/by-id/CA+TgmoY0=bT_xBP8csR=MFE=FxGE2n2-me2-31jBOgEcLvW7ug@mail.gmail.com
------
Regards,
Alexander Korotkov
Supabase
Hi, Alexander!
Thank you for notes.
1.
+ 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);Similar fragments are present in SplitPartitionMoveRows() and
MergePartitionsMoveRows(). Do you think we could use ExecCopySlot()
(or similar) instead?
I think ExecCopySlot function is not suitable here because of
tts_virtual_materialize function
(ExecCopySlot -> tts_virtual_copyslot -> tts_virtual_materialize).
It is good to use the same data in insertslot as in srcslot, without
materialization.
Therefore, it seems to me that it is better not to change the existing
code, especially since it is similar to the code of the ATRewriteTable
function [1]https://github.com/postgres/postgres/blob/71ea0d6795438f95f4ee6e35867058c44b270d51/src/backend/commands/tablecmds.c#L6361 and is understandable.
2.
The presence of the same name in the split partition list is checked
with equal() (similar concern was already raised about the merge case
[1]). If one of the names is schema-qualified, the error message is
different. Could we make them the same?
Corrected. Added namespace comparison for this case.
3.
+ /* Search partition for current slot srcslot. */ + foreach(listptr, partContexts) + { + pc = (SplitPartitionContext *) lfirst(listptr); + + /* skip DEFAULT partition */ + if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext)) + { + found = true; + break; + } + } I see we're searching for a partition to place each row using the sequential application of partition constraints. I concerned if this could be exhausting when the number of new partitions is large. Could we use something like binary search here?
I think binary search for this case would make the code much more
complicated. And is binary search really needed for real cases?
I assume that the main use of SPLIT PARTITION will be split into a
small number of partitions, for example:
* for extracting partition from the DEFAULT partition;
* splitting partition for big intreval into partitions for smaller
intervals (for example, splitting a partition for quarter/year into
partitions for months).
* ...
In these cases, we highly likely won't need binary search.
4.
New split/drop commands do the full reorganization of the involved
partitions. As Robert previously stated, there are other
possible strategies. While they are hard to implement, I don't think
we need them in the initial version. But I think it's worth
mentioning in the docs that we're completely rewriting the involved
partitions. And this is not recommended to use for merging very big
partitions with small ones, and splitting a small fraction of rows out
of a very big partition.
Added notes to documentation (sorry my poor English).
5.
Both patches could use pgindent run.
Fixed.
Links
-----
[1]: https://github.com/postgres/postgres/blob/71ea0d6795438f95f4ee6e35867058c44b270d51/src/backend/commands/tablecmds.c#L6361
https://github.com/postgres/postgres/blob/71ea0d6795438f95f4ee6e35867058c44b270d51/src/backend/commands/tablecmds.c#L6361
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From e5ba99a7c4324eb958ec8815b37170a4629a3ef5 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v52 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 120 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/heap.c | 4 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 909 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 149 +++
src/backend/partitioning/partbounds.c | 194 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 5 +-
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 | 1105 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 796 ++++++++++++
21 files changed, 3627 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..29a0ff5cdb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,14 +1161,108 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use command to merge very big partitions with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1409,7 +1505,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1949,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index fd6537567e..7514eab4cd 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr,
bool is_enforced, bool is_validated, bool is_local,
int16 inhcount, bool is_no_inherit, bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr,
bool allow_merge, bool is_local,
bool is_enforced,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index c6dd2e020d..079b1725cf 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4833,6 +4835,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5268,6 +5274,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5664,6 +5675,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);
@@ -6704,6 +6723,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:
@@ -20193,6 +20214,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20394,23 +20446,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22057,3 +22094,841 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /* Build the needed expression execution states. */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_FOREIGN:
+ /* Nothing to do here. */
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ /* Expression already planned. */
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+ }
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = ccon->contype;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also reevaulate check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ ExprContext *econtext;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ econtext = GetPerTupleExprContext(estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index db43034b9d..6e3b895f72 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17929,6 +17947,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18556,6 +18575,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index afcf54169c..ebca11f673 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3510,6 +3513,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3787,6 +3922,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..170dd7419f 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,197 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8b10f2313f..1cf0949fbb 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,6 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3022,6 +3023,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..2e97b656e2 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions, for MERGE PARTITION
+ * command */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2475,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 e3c669a29c..0dca684955 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -107,6 +107,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..5159fd37d8
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1105 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT * FROM sales_date;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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;
+ salesperson_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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
+(1 row)
+
+DROP TABLE t;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+DROP TABLE t;
+SET search_path = pg_temp, partitions_merge_schema, public;
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..bb5386fe38
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,796 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (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_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('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 salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+DROP TABLE t;
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+SET search_path = partitions_merge_schema, public;
+
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+DROP TABLE t;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+
+EXECUTE get_partition_info('{t}');
+
+DEALLOCATE get_partition_info;
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v52-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v52-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 9ea4ff61fc0bc47e31ebb3c8bb83b37ee5eae95f Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v52 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 102 +-
src/backend/commands/tablecmds.c | 444 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 90 +-
src/backend/partitioning/partbounds.c | 712 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 22 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1574 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1141 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4399 insertions(+), 30 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 29a0ff5cdb..0dcdaa05c0 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,78 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from split partition into them, which can take a long time.
+ So it is not recommended to use command for splitting a small fraction of
+ rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1262,7 +1338,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1506,7 +1583,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1516,7 +1593,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1949,6 +2027,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 079b1725cf..d5395e6ebe 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5279,6 +5286,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5683,6 +5695,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6725,6 +6745,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22932,3 +22954,425 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and
+ * mark stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace
+ * is selected.
+ */
+ sps->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 6e3b895f72..81f6e5e362 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18016,6 +18050,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18656,6 +18691,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index ebca11f673..2449e62c02 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3517,9 +3517,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
* Partition with OID partRelOid must be locked before function call.
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3529,25 +3531,71 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3626,7 +3674,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3914,7 +3962,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3936,6 +3984,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4366,13 +4428,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4381,9 +4443,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4391,7 +4453,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 170dd7419f..3a23ea43bd 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,7 +5033,7 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
@@ -5030,7 +5041,9 @@ check_two_partitions_bounds_range(Relation parent,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5134,6 +5147,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5172,3 +5187,692 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+ bool result = false;
+
+ /*
+ * Need to compare namespaces? One of the schema names may be
+ * undefined, but the schemas may still be equal.
+ */
+ if ((sps->name->schemaname && !sps2->name->schemaname) ||
+ (!sps->name->schemaname && sps2->name->schemaname))
+ {
+ Oid nspid = RangeVarGetCreationNamespace(sps->name);
+ Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid == nspid2)
+ result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
+ }
+ else
+ result = equal(sps->name, sps2->name);
+
+ if (result)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 1cf0949fbb..efe65cf944 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,7 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3012,10 +3012,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3023,6 +3023,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 2e97b656e2..7f9e38d5b5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,15 +964,28 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * 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 and for
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions, for MERGE PARTITION
- * command */
+ List *partlist; /* list of partitions, for MERGE/SPLIT
+ * PARTITION command */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 0dca684955..404a7fd832 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i 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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..03b442587d
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1574 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..06671c3b8d
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1141 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_indexscan = ON;
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+SET enable_indexscan = ON;
+SET enable_seqscan = ON;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e6f2e93b2d..c61f0f405a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2776,6 +2776,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2842,6 +2843,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
this time, I only checked
v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
typedef struct PartitionCmd
{
NodeTag type;
RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
List *partlist; /* list of partitions, for MERGE PARTITION
* command */
bool concurrent;
} PartitionCmd;
The field "partlist" comments are not very helpful, IMO.
I think the following is more descriptive.
/* list of partitions to be merged, used only in ALTER TABLE MERGE PARTITION */
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name,
+ AccessExclusiveLock,
+ false,
+ RangeVarCallbackOwnsRelation,
+ NULL);
here "false" should be "0"?
+ /* 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),
+ pstate);
+ }
the comment should be
+ /* Ranges of partitions should be adjacent */
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -102,11 +102,11 @@ static ObjectAddress AddNewRelationType(const
char *typeName,
Oid new_row_type,
Oid new_array_type);
static void RelationRemoveInheritance(Oid relid);
+static void StoreConstraints(Relation rel, List *cooked_constraints,
+ bool is_internal);
-static void StoreConstraints(Relation rel, List *cooked_constraints,
- bool is_internal);
Is this change necessary?
in createPartitionTable
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
....
+ newPartName->relpersistence,
....
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent
relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary
relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
i raised this question in [1]/messages/by-id/CACJufxHM0sD8opy2hUxXLcdY3CQOCaMfsQtJs7yF3TS2YxSqKg@mail.gmail.com, you replied at [2]/messages/by-id/195b67ee-ef41-4451-9396-844442eef1a4@postgrespro.ru.
I still think it's not intuitive.
parent->relpersistence is fixed. and newRel->relpersistence is the same as
the same as newPartName->relpersistence, see heap_create_with_catalog.
These relpersistence error checks can happen before heap_create_with_catalog.
I added a regress test for src/test/modules/test_ddl_deparse.
I refactored regress to make
src/test/regress/expected/partition_merge.out less verbose.
[1]: /messages/by-id/CACJufxHM0sD8opy2hUxXLcdY3CQOCaMfsQtJs7yF3TS2YxSqKg@mail.gmail.com
[2]: /messages/by-id/195b67ee-ef41-4451-9396-844442eef1a4@postgrespro.ru
Attachments:
v52-0001-misc-minor-fix.no-cfbotapplication/octet-stream; name=v52-0001-misc-minor-fix.no-cfbotDownload
From 1fcfa1d1a7ee03ae8591d04117bd8f13842c67e0 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 20 Aug 2025 15:25:35 +0800
Subject: [PATCH v52 1/1] misc minor fix
* misc regress tests fix
* check persistence before call heap_create_with_catalog in
createPartitionTable
---
src/backend/commands/tablecmds.c | 42 +++----
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
src/test/regress/expected/partition_merge.out | 107 +++++-------------
src/test/regress/sql/partition_merge.sql | 12 +-
5 files changed, 57 insertions(+), 112 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 079b1725cf1..1d35acf4e6f 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22498,6 +22498,27 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
errcode(ERRCODE_DUPLICATE_TABLE),
errmsg("relation \"%s\" already exists", newPartName->relname));
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
/* Create the relation. */
newRelId = heap_create_with_catalog(newPartName->relname,
namespaceId,
@@ -22536,27 +22557,6 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
/* Find or create work queue entry for newly created table. */
new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
- /*
- * We intended to create the partition with the same persistence as the
- * parent table, but we still need to recheck because that might be
- * affected by the search_path. If the parent is permanent, so must be
- * all of its partitions.
- */
- if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
- newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
- ereport(ERROR,
- errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
- RelationGetRelationName(parent_rel)));
-
- /* Permanent rels cannot be partitions belonging to temporary parent */
- if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
- parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
- ereport(ERROR,
- errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
- RelationGetRelationName(parent_rel)));
-
/* Create constraints, default values and generated values */
createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a341..c403c2f569f 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d4..31e69100a30 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 5159fd37d82..21a078f138e 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -254,95 +254,40 @@ INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VAL
('Manager1', 2022, 3, 3),
('Manager2', 2022, 3, 4),
('Manager3', 2022, 5, 1);
-SELECT * FROM sales_date;
- salesperson_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
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
(9 rows)
-SELECT * FROM sales_dec2022;
- salesperson_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;
- salesperson_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;
- salesperson_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;
- salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
('Manager1', 2022, 1, 10),
('Manager2', 2022, 2, 10);
-SELECT * FROM sales_date;
- salesperson_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
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
(11 rows)
-SELECT * FROM sales_dec2022;
- salesperson_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;
- salesperson_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;
- salesperson_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
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index bb5386fe381..fef59fbc5d5 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -187,11 +187,7 @@ INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VAL
('Manager2', 2022, 3, 4),
('Manager3', 2022, 5, 1);
-SELECT * FROM sales_date;
-SELECT * FROM sales_dec2022;
-SELECT * FROM sales_jan2022;
-SELECT * FROM sales_feb2022;
-SELECT * FROM sales_other;
+SELECT tableoid::regclass, * FROM sales_date;
ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
@@ -199,11 +195,7 @@ INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VAL
('Manager1', 2022, 1, 10),
('Manager2', 2022, 2, 10);
-SELECT * FROM sales_date;
-SELECT * FROM sales_dec2022;
-SELECT * FROM sales_jan_feb2022;
-SELECT * FROM sales_other;
-
+SELECT tableoid::regclass, * FROM sales_date;
DROP TABLE sales_date;
--
--
2.34.1
On Wed, Aug 20, 2025 at 5:22 PM jian he <jian.universality@gmail.com> wrote:
this time, I only checked
v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtypedef struct PartitionCmd
{
NodeTag type;
RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
List *partlist; /* list of partitions, for MERGE PARTITION
* command */
bool concurrent;
} PartitionCmd;
/*
* PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
*/
typedef struct PartitionCmd
the above comments also need to be updated?
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
``+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';``
may ultimately fall back to using seqscan?
so we need to use
``explain(costs off)`` to see if it use indexscan or not.
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel)));
this error is unlikely to happen, we can simply use elog(ERROR, ....),
rather than ereport.
evaluateGeneratedExpressionsAndCheckConstraints seem not necessary?
we should make the MergePartitionsMoveRows code pattern aligned with
ATRewriteTable.
by comparing these two function, i found that before call table_scan_getnextslot
we need to switch memory context to EState->ecxt_per_tuple_memor
please check the attached changes.
Attachments:
v52-0001-refactor-MergePartitionsMoveRows.no-cfbotapplication/octet-stream; name=v52-0001-refactor-MergePartitionsMoveRows.no-cfbotDownload
From a89bce4f39c16dc9e3ad247401b238554e520b87 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Thu, 21 Aug 2025 10:49:50 +0800
Subject: [PATCH v52 1/1] refactor MergePartitionsMoveRows
mainly make MergePartitionsMoveRows more aligned with ATRewriteTable.
based on v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
also convert one ereport(ERROR...) to elog(ERROR ...)
within createTableConstraints.
---
src/backend/commands/tablecmds.c | 105 ++++++++++++++-----------------
1 file changed, 48 insertions(+), 57 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index cc24a92c504..9ecd1838077 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22133,52 +22133,6 @@ buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EStat
}
}
-/*
- * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
- * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
- * the new tuple (insertslot) of new partition (newPartRel).
- */
-static void
-evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
- Relation newPartRel,
- TupleTableSlot *insertslot,
- ExprContext *econtext)
-{
- econtext->ecxt_scantuple = insertslot;
-
- foreach_ptr(NewColumnValue, ex, tab->newvals)
- {
- if (!ex->is_generated)
- continue;
-
- insertslot->tts_values[ex->attnum - 1]
- = ExecEvalExpr(ex->exprstate,
- econtext,
- &insertslot->tts_isnull[ex->attnum - 1]);
- }
-
- foreach_ptr(NewConstraint, con, tab->constraints)
- {
- switch (con->contype)
- {
- case CONSTR_CHECK:
- if (!ExecCheck(con->qualstate, econtext))
- ereport(ERROR,
- errcode(ERRCODE_CHECK_VIOLATION),
- errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
- con->name, RelationGetRelationName(newPartRel)),
- errtableconstraint(newPartRel, con->name));
- break;
- case CONSTR_NOTNULL:
- case CONSTR_FOREIGN:
- /* Nothing to do here */
- break;
- default:
- elog(ERROR, "unrecognized constraint type: %d",
- (int) con->contype);
- }
- }
-}
/*
* getAttributesList: build a list of columns (ColumnDef) based on parent_rel
@@ -22363,12 +22317,9 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
* possible to guarantee it would work in future.
*/
if (found_whole_row)
- ereport(ERROR,
- errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("cannot convert whole-row table reference"),
- errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".",
- ccname,
- RelationGetRelationName(parent_rel)));
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
constr = makeNode(Constraint);
constr->contype = CONSTR_CHECK;
@@ -22580,7 +22531,6 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
{
CommandId mycid;
EState *estate;
- ExprContext *econtext;
AlteredTableInfo *tab;
ListCell *ltab;
@@ -22597,8 +22547,6 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
buildExpressionExecutionStates(tab, newPartRel, estate);
- econtext = GetPerTupleExprContext(estate);
-
mycid = GetCurrentCommandId(true);
/* Prepare a BulkInsertState for table_tuple_insert. */
@@ -22609,12 +22557,16 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
foreach_oid(merging_oid, mergingPartitions)
{
+ ExprContext *econtext;
TupleTableSlot *srcslot;
TupleConversionMap *tuple_map;
TableScanDesc scan;
+ MemoryContext oldCxt;
Snapshot snapshot;
Relation mergingPartition;
+ econtext = GetPerTupleExprContext(estate);
+
/*
* Partition is already locked in the transformPartitionCmdForMerge
* function.
@@ -22635,6 +22587,12 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
snapshot = RegisterSnapshot(GetLatestSnapshot());
scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
{
TupleTableSlot *insertslot;
@@ -22676,9 +22634,41 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
* the new tuple. We assume these columns won't reference each
* other, so that there's no ordering dependency.
*/
- evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
- insertslot, econtext);
+ econtext->ecxt_scantuple = insertslot;
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ /* Now check any constraints */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
/* Write the tuple out to the new relation. */
table_tuple_insert(newPartRel, insertslot, mycid,
ti_options, bistate);
@@ -22686,6 +22676,7 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
ResetExprContext(econtext);
}
+ MemoryContextSwitchTo(oldCxt);
table_endscan(scan);
UnregisterSnapshot(snapshot);
--
2.34.1
On Thu, Aug 21, 2025 at 10:53 AM jian he <jian.universality@gmail.com> wrote:
this time, I only checked
v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
hi.
we may need to change checkPartition.
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022,
sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions
don't have sub-partitions
+ERROR: "sales_apr2022" is not a table
the above error message seems not intuitive to me.
IMV, the error message pattern should be something like:
ERROR: can not merge relation \"%s\" with other partitions
DETAIL: "sales_apr2022" is not a table
HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions
don't have sub-partition
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ * Partition with OID partRelOid must be locked before function call.
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
"Partition with OID partRelOid must be locked before function call."
we can remove this sentence.
otherwise, "function call" seems confusing?
+SET search_path = pg_temp, partitions_merge_schema, public;
+
+BEGIN;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM
pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+DEALLOCATE get_partition_info;
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
"+-- Can't merge temporary partitions into a persistent partition"
means
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
should error out, but it didn't.
then I found out:
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
....
+ /*
+ * Look up existing relation by new partition name, check we have
+ * permission to create there, lock it against concurrent drop, and mark
+ * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
+ * selected.
+ */
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
``cmd->name->relpersistence`` will be adjusted in
RangeVarGetAndCheckCreationNamespace->RangeVarAdjustRelationPersistence.
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
seems wrong?
comments "stmt->relation" not sure what it refers to?
attached patch did following the changes:
* remove line ``cmd->name->relpersistence = rel->rd_rel->relpersistence;``
* refactor relpersistence, temp schema related regress tests.
Attachments:
v52-0001-refactor-relpersistence-related-issue.no-cfbotapplication/octet-stream; name=v52-0001-refactor-relpersistence-related-issue.no-cfbotDownload
From a1c779ff030b9b2ffaeb15806cafe0c7fed34f43 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Thu, 21 Aug 2025 14:28:33 +0800
Subject: [PATCH v52 1/1] refactor relpersistence related issue
---
src/backend/commands/tablecmds.c | 1 -
src/test/regress/expected/partition_merge.out | 60 +++++++++++--------
src/test/regress/sql/partition_merge.sql | 51 ++++++++--------
3 files changed, 62 insertions(+), 50 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index cc24a92c504..0d520745670 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22793,7 +22793,6 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
* stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is
* selected.
*/
- cmd->name->relpersistence = rel->rd_rel->relpersistence;
RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
/*
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 5159fd37d82..00ed2516c68 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -656,28 +656,6 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
--
--- Try to MERGE partitions of temporary table.
---
-CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
-CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
-CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
-EXECUTE get_partition_info('{t}');
- oid | relpersistence | relkind | inhdetachpending | pg_get_expr
---------+----------------+---------+------------------+----------------------------
- tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
- tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
-(2 rows)
-
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
--- Partition should be temporary.
-EXECUTE get_partition_info('{t}');
- oid | relpersistence | relkind | inhdetachpending | pg_get_expr
---------+----------------+---------+------------------+----------------------------
- tp_0_2 | t | r | f | FOR VALUES FROM (0) TO (2)
-(1 row)
-
-DROP TABLE t;
---
-- Check the partition index name if the partition name is the same as one
-- of the merged partitions.
--
@@ -703,8 +681,37 @@ Not-null constraints:
DROP TABLE t;
--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4; --error
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
-- Try mixing permanent and temporary partitions.
--
+BEGIN;
SET search_path = partitions_merge_schema, pg_temp, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
@@ -722,17 +729,19 @@ EXECUTE get_partition_info('{t}');
tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
(2 rows)
+SAVEPOINT s;
SET search_path = pg_temp, partitions_merge_schema, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
SET search_path = partitions_merge_schema, public;
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
ERROR: cannot create a temporary relation as partition of permanent relation "t"
-DROP TABLE t;
-SET search_path = pg_temp, partitions_merge_schema, public;
+ROLLBACK;
BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
@@ -749,11 +758,12 @@ EXECUTE get_partition_info('{t}');
tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
(2 rows)
-DEALLOCATE get_partition_info;
SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
ROLLBACK;
+DEALLOCATE get_partition_info;
-- Check the new partition inherits parent's tablespace
SET search_path = partitions_merge_schema, public;
CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index bb5386fe381..0812d33186c 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -449,21 +449,6 @@ DROP TABLE t3;
DROP TABLE t2;
DROP TABLE t1;
---
--- Try to MERGE partitions of temporary table.
---
-CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
-CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
-CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
-
-EXECUTE get_partition_info('{t}');
-
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
-
--- Partition should be temporary.
-EXECUTE get_partition_info('{t}');
-
-DROP TABLE t;
--
-- Check the partition index name if the partition name is the same as one
@@ -483,48 +468,66 @@ ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4; --error
+ROLLBACK;
+
--
-- Try mixing permanent and temporary partitions.
--
+BEGIN;
SET search_path = partitions_merge_schema, pg_temp, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
-
EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
SET search_path = pg_temp, partitions_merge_schema, public;
-
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK TO SAVEPOINT s;
SET search_path = partitions_merge_schema, public;
-
-- Can't merge persistent partitions into a temporary partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
-DROP TABLE t;
-
-SET search_path = pg_temp, partitions_merge_schema, public;
+ROLLBACK;
BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
-
EXECUTE get_partition_info('{t}');
-DEALLOCATE get_partition_info;
-
SET search_path = partitions_merge_schema, pg_temp, public;
-- Can't merge temporary partitions into a persistent partition
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ROLLBACK;
+DEALLOCATE get_partition_info;
+
-- Check the new partition inherits parent's tablespace
SET search_path = partitions_merge_schema, public;
CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
--
2.34.1
On Thu, Aug 21, 2025 at 2:45 PM jian he <jian.universality@gmail.com> wrote:
On Thu, Aug 21, 2025 at 10:53 AM jian he <jian.universality@gmail.com> wrote:
this time, I only checked
v52-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch
hi.
+static void
+check_two_partitions_bounds_range(Relation parent,
+{
....
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to the upper
bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition
bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
I propose change it to:
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("can not merge partition \"%s\" together with
partition \"%s\"",
second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not
equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
errhint("ALTER TABLE ... MERGE PARTITIONS requires the
partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
<para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER
TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
I am not sure last sentence "merge three monthly partitions into one
quarter partition:"
is correct.
buildExpressionExecutionStates seems not needed, same reason as
mentioned before,
code pattern aligned with ATRewriteTable.
while at it, also did some minor changes.
Attachments:
v52-0001-refactor-buildExpressionExecutionStates.no-cfbotapplication/octet-stream; name=v52-0001-refactor-buildExpressionExecutionStates.no-cfbotDownload
From 82fc52c6382c9a05a48076881812dac0768d2ce2 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 22 Aug 2025 11:31:08 +0800
Subject: [PATCH v52 1/1] refactor buildExpressionExecutionStates
buildExpressionExecutionStates seems not necessary,
so remove it.
while at it, also did some minor refactor.
---
src/backend/commands/tablecmds.c | 68 +++++++++++++-------------------
1 file changed, 28 insertions(+), 40 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index cc24a92c504..bf50d209d1c 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22097,42 +22097,6 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
}
-/*
- * buildExpressionExecutionStates: build the needed expression execution states
- * for new partition (newPartRel) checks and initialize expressions for
- * generated columns. All expressions should be created in "tab"
- * (AlteredTableInfo structure).
- */
-static void
-buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
-{
- /* Build the needed expression execution states. */
- foreach_ptr(NewConstraint, con, tab->constraints)
- {
- switch (con->contype)
- {
- case CONSTR_CHECK:
- con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
- break;
- case CONSTR_FOREIGN:
- /* Nothing to do here. */
- break;
- case CONSTR_NOTNULL:
- /* Nothing to do here. */
- break;
- default:
- elog(ERROR, "unrecognized constraint type: %d",
- (int) con->contype);
- }
- }
-
- foreach_ptr(NewColumnValue, ex, tab->newvals)
- {
- /* Expression already planned. */
- ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
- }
-}
-
/*
* evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
* expressions for "tab" (AlteredTableInfo structure) whose inputs come from
@@ -22400,11 +22364,12 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
*/
foreach_ptr(CookedConstraint, ccon, cookedConstraints)
{
- if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK)
+ if (!ccon->skip_validation)
{
Node *qual;
Bitmapset *attnums = NULL;
+ Assert(ccon->contype == CONSTR_CHECK);
qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
pull_varattnos(qual, 1, &attnums);
@@ -22419,7 +22384,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
newcon->name = ccon->name;
- newcon->contype = ccon->contype;
+ newcon->contype = CONSTR_CHECK;
newcon->qual = qual;
tab->constraints = lappend(tab->constraints, newcon);
@@ -22573,7 +22538,7 @@ createPartitionTable(List **wqueue, RangeVar *newPartName,
/*
* MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
* of the partitioned table and move rows into the new partition
- * (newPartRel). We also reevaulate check constraints against these rows.
+ * (newPartRel). We also vertify check constraints against these rows.
*/
static void
MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
@@ -22595,7 +22560,30 @@ MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPart
/* Generate the constraint and default execution states. */
estate = CreateExecutorState();
- buildExpressionExecutionStates(tab, newPartRel, estate);
+ /*
+ * Build the needed expression execution states.
+ * Here, we expect only NOT NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ /* we already expanded virtual expression in createTableConstraints */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
econtext = GetPerTupleExprContext(estate);
--
2.34.1
Hi!
Thanks for the notes and patches!
1.
/* list of partitions, for MERGE PARTITION command */
...
The field "partlist" comments are not very helpful, IMO.
I think the following is more descriptive.
/* list of partitions to be merged, used only in ALTER TABLE MERGE
PARTITION */
Corrected.
2.
+ partOid = RangeVarGetRelidExtended(name, + AccessExclusiveLock, + false, + RangeVarCallbackOwnsRelation, + NULL); here "false" should be "0"?
Corrected.
3.
the comment should be
+ /* Ranges of partitions should be adjacent */
Corrected.
4.
+static void StoreConstraints(Relation rel, List *cooked_constraints, + bool is_internal); -static void StoreConstraints(Relation rel, List *cooked_constraints, - bool is_internal);Is this change necessary?
Corrected.
5.
i raised this question in [1], you replied at [2].
I still think it's not intuitive.
parent->relpersistence is fixed. and newRel->relpersistence is the
same as the same as newPartName->relpersistence, see
heap_create_with_catalog. These relpersistence error checks can
happen before heap_create_with_catalog.
I added a regress test for src/test/modules/test_ddl_deparse.
I refactored regress to make
src/test/regress/expected/partition_merge.out less verbose.
I'm sorry, I misunderstood the point.
Applied.
6.
/*
* PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION
commands
*/
typedef struct PartitionCmd
the above comments also need to be updated?
Updated.
(Previously the comment was updated for SPLIT PARTITION command only.)
7.
``+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';``
may ultimately fall back to using seqscan?
so we need to use
``explain(costs off)`` to see if it use indexscan or not.
Corrected.
8.
...
+ RelationGetRelationName(parent_rel)));
this error is unlikely to happen, we can simply use elog(ERROR, ....),
rather than ereport.
Applied.
9.
evaluateGeneratedExpressionsAndCheckConstraints seem not necessary?
The "evaluateGeneratedExpressionsAndCheckConstraints" function is used
for both commands (SPLIT and MERGE), so I prefer to keep it
(probably, code duplication is worse).
10.
we should make the MergePartitionsMoveRows code pattern aligned with
ATRewriteTable.
by comparing these two function, i found that before call
table_scan_getnextslot we need to switch memory context to
EState->ecxt_per_tuple_memor
Thanks, that is correct. Applied.
11.
we may need to change checkPartition.
...
IMV, the error message pattern should be something like:
ERROR: can not merge relation \"%s\" with other partitions
DETAIL: "sales_apr2022" is not a table
HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions
don't have sub-partition
This error is generated if the condition
"if (partRel->rd_rel->relkind!= RELKIND_RELATION)"
is true. But error message pattern
"can not merge relation ... with other partitions"
is correct for RELKIND_PARTITIONED_TABLE only. Separate messages for
each of the relation types (RELKIND_VIEW, RELKIND_FOREIGN_TABLE, ...)
looks a bit complicated (see example [1]https://github.com/postgres/postgres/blob/989b2e4d5c95f6b183e76f3eb06d2d360651ccf2/src/backend/commands/copyto.c#L649).
Might be we can replace error message "... is not a table" to
"... is not a simple partition"?
12.
+checkPartition(Relation rel, Oid partRelOid)
"Partition with OID partRelOid must be locked before function call."
we can remove this sentence.
otherwise, "function call" seems confusing?
Removed.
13.
+ cmd->name->relpersistence = rel->rd_rel->relpersistence;
seems wrong?
comments "stmt->relation" not sure what it refers to?
Applied and corrected the same for SPLIT PARTITION.
14.
...
I propose change it to:
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("can not merge partition \"%s\" together with partition
\"%s\"",
second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the
upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
errhint("ALTER TABLE ... MERGE PARTITIONS requires the
partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
Changed.
15.
buildExpressionExecutionStates seems not needed, same reason as
mentioned before,
code pattern aligned with ATRewriteTable.
"buildExpressionExecutionStates" function is used for both commands
(SPLIT and MERGE). Probably, is better to keep this function?
16.
while at it, also did some minor changes.
Applied.
Links
-----
[1]: https://github.com/postgres/postgres/blob/989b2e4d5c95f6b183e76f3eb06d2d360651ccf2/src/backend/commands/copyto.c#L649
https://github.com/postgres/postgres/blob/989b2e4d5c95f6b183e76f3eb06d2d360651ccf2/src/backend/commands/copyto.c#L649
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v53-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v53-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 42fb8a89491e54c1bdb9c29e944ed05a2adb0d42 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v53 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 120 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 912 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
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/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1102 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 797 ++++++++++++
22 files changed, 3635 insertions(+), 25 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..29a0ff5cdb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,14 +1161,108 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use command to merge very big partitions with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1409,7 +1505,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1949,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 082a3575d6..5a3c53d3e5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4833,6 +4835,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5268,6 +5274,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5664,6 +5675,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);
@@ -6704,6 +6723,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:
@@ -20193,6 +20214,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20394,23 +20446,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22058,3 +22095,844 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity for new partition. */
+ def->identity = attribute->attidentity;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ /*
+ * Prevent this for the same reason as for constraints below. Note
+ * that defaults cannot contain any vars, so it's OK that the
+ * error message refers to generated columns.
+ */
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index db43034b9d..6e3b895f72 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17929,6 +17947,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18556,6 +18575,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index afcf54169c..333c51d933 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3510,6 +3513,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3787,6 +3919,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8b10f2313f..1cf0949fbb 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,6 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3022,6 +3023,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 9f1e997d81..2040e1c57a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..f62622f8ac
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1102 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+--------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+(1 row)
+
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+------------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..cfb6083e12
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,797 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test: we can't merge partitions with different owners
+CREATE ROLE regress_partitions_merge_alice;
+CREATE ROLE regress_partitions_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
+SET SESSION AUTHORIZATION regress_partitions_merge_alice;
+CREATE TABLE tp_0_1(i int);
+RESET SESSION AUTHORIZATION;
+SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+CREATE TABLE tp_1_2(i int);
+RESET SESSION AUTHORIZATION;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partitions_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partitions_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
+DROP ROLE regress_partitions_merge_alice;
+DROP ROLE regress_partitions_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v53-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v53-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 7e5c9d534cc8eb273c7cd043254814f56274543d Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v53 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 102 +-
src/backend/commands/tablecmds.c | 438 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 88 +-
src/backend/partitioning/partbounds.c | 719 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1642 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1149 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4480 insertions(+), 32 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 29a0ff5cdb..0dcdaa05c0 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,78 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from split partition into them, which can take a long time.
+ So it is not recommended to use command for splitting a small fraction of
+ rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1262,7 +1338,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1506,7 +1583,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1516,7 +1593,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1949,6 +2027,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5a3c53d3e5..adcb7f6c6a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5279,6 +5286,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5683,6 +5695,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6725,6 +6745,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22936,3 +22958,419 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 6e3b895f72..81f6e5e362 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18016,6 +18050,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18656,6 +18691,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 333c51d933..87469f69ea 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3516,9 +3516,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3528,25 +3530,69 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3623,7 +3669,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3911,7 +3957,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3933,6 +3979,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4363,13 +4423,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4378,9 +4438,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4388,7 +4448,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..c988406b25 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,17 +5033,22 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
+ merge_split
+ ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname)
+ : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5152,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5192,692 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+ bool result = false;
+
+ /*
+ * Need to compare namespaces? One of the schema names may be
+ * undefined, but the schemas may still be equal.
+ */
+ if ((sps->name->schemaname && !sps2->name->schemaname) ||
+ (!sps->name->schemaname && sps2->name->schemaname))
+ {
+ Oid nspid = RangeVarGetCreationNamespace(sps->name);
+ Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid == nspid2)
+ result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
+ }
+ else
+ result = equal(sps->name, sps2->name);
+
+ if (result)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 1cf0949fbb..efe65cf944 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,7 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3012,10 +3012,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3023,6 +3023,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2040e1c57a..2ad9f97cbe 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..f3647e77d5
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1642 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..dfd5537b6f
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1149 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid, sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid, salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a13e816289..12bfa30c6c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Tue, Aug 26, 2025 at 4:05 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Thanks for the notes and patches!
hi.
ORDER BY regclass seems not stable, see
https://git.postgresql.org/cgit/postgresql.git/commit/?id=17bcf4f5450430f67b744c225566c9e0e6413e95
some of the SQL tests seem not necessary, so I refactored tests.
+static List *
+getAttributesList(Relation parent_rel)
+{
.....
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
....
+
+ /* Add to column list */
+ colList = lappend(colList, def);
+
+ /*
+ * Although we don't transfer the column's default/generation
+ * expression now, we need to mark it GENERATED if appropriate.
+ */
+ if (attribute->atthasdef && attribute->attgenerated)
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression if requested */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+ }
+
+ return colList;
the last part seems intuitive?
"colList = lappend(colList, def);" should be at the end of the for loop?
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+-- Not-null constraint name should be 'tp_1_2_i_not_null'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats
target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
"-- Not-null constraint name should be 'tp_1_2_i_not_null'.
Comments conflict with the result.
+ /*
+ * We reject whole-row variables because the whole point of LIKE is
+ * that the new table's rowtype might later diverge from the parent's.
+ * So, while translation might be possible right now, it wouldn't be
+ * possible to guarantee it would work in future.
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to
table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
the above comment needs change, since LIKE is not related to here.
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *)
expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ break;
here, we don't need expand_generated_columns_in_expr, the comment also
explained it.
the attached patch is the changes for the above comments.
Attachments:
v53-0001-refactor-src-test-regress-sql-partition_merge.sql.no-cfbotapplication/octet-stream; name=v53-0001-refactor-src-test-regress-sql-partition_merge.sql.no-cfbotDownload
From 1adf882c6971282d90ed62e26b5106ce3b034ffa Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 29 Aug 2025 15:34:18 +0800
Subject: [PATCH v53 1/1] refactor src/test/regress/sql/partition_merge.sql
also minor refactror getAttributesList
---
src/backend/commands/tablecmds.c | 20 ++--
src/test/regress/expected/partition_merge.out | 101 ++++++++----------
src/test/regress/sql/partition_merge.sql | 46 ++++----
3 files changed, 72 insertions(+), 95 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5a3c53d3e59..8fa1a377a14 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22120,7 +22120,7 @@ buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EStat
* We already expanded virtual expression in
* createTableConstraints.
*/
- con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate);
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
break;
case CONSTR_NOTNULL:
/* Nothing to do here. */
@@ -22211,27 +22211,23 @@ getAttributesList(Relation parent_rel)
def->is_not_null = attribute->attnotnull;
- /* Copy identity for new partition. */
+ /* Copy identity */
def->identity = attribute->attidentity;
- /* Add to column list */
- colList = lappend(colList, def);
-
- /*
- * Although we don't transfer the column's default/generation
- * expression now, we need to mark it GENERATED if appropriate.
- */
- if (attribute->atthasdef && attribute->attgenerated)
- def->generated = attribute->attgenerated;
+ /* Copy attgenerated */
+ def->generated = attribute->attgenerated;
def->storage = attribute->attstorage;
- /* Likewise, copy compression if requested */
+ /* Likewise, copy compression */
if (CompressionMethodIsValid(attribute->attcompression))
def->compression =
pstrdup(GetCompressionMethodName(attribute->attcompression));
else
def->compression = NULL;
+
+ /* Add to column list */
+ colList = lappend(colList, def);
}
return colList;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index f62622f8ac9..69f866721fe 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -144,13 +144,9 @@ SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemanam
partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
(1 row)
-SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
------------------------------------------------+----------------+------------------+--------------+------------
- sales_jan2022 | 1 | May | 1000 | 01-31-2022
- sales_jan2022 | 10 | Halder | 350 | 01-28-2022
- sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
- sales_others | 14 | Smith | 510 | 05-04-2022
partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
@@ -161,6 +157,10 @@ SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
(14 rows)
-- Use indexscan for testing indexes
@@ -437,7 +437,7 @@ INSERT INTO sales_range VALUES
(12, 'Plato', 350, '2022-03-19'),
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
---------------------+----------------+------------------+--------------+------------
sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
@@ -447,7 +447,7 @@ SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_i
(4 rows)
ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
-SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
---------------+----------------+------------------+--------------+------------
sales_apr_all | 3 | Ford | 2000 | 04-30-2022
@@ -549,13 +549,9 @@ EXECUTE get_partition_info('{sales_list}');
sales_others | p | r | f | DEFAULT
(3 rows)
-SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
------------+----------------+------------------+----------------+--------------+------------
- sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
- sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
- sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
- sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
@@ -566,6 +562,10 @@ SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
(14 rows)
-- Use indexscan for testing indexes after merging partitions
@@ -651,7 +651,6 @@ CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
--- Not-null constraint name should be 'tp_1_2_i_not_null'.
\d+ tp_1_2
Table "partitions_merge_schema.tp_1_2"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
@@ -807,66 +806,56 @@ CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
ERROR: must be owner of table t
RESET SESSION AUTHORIZATION;
ALTER TABLE t OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
ERROR: must be owner of table tp_0_1
RESET SESSION AUTHORIZATION;
ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
ERROR: must be owner of table tp_1_2
RESET SESSION AUTHORIZATION;
ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --ok
RESET SESSION AUTHORIZATION;
DROP TABLE t;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
-DROP ROLE regress_partition_merge_alice;
-DROP ROLE regress_partition_merge_bob;
-- Test: we can't merge partitions with different owners
-CREATE ROLE regress_partitions_merge_alice;
-CREATE ROLE regress_partitions_merge_bob;
-GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
-GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
-SET SESSION AUTHORIZATION regress_partitions_merge_alice;
CREATE TABLE tp_0_1(i int);
-RESET SESSION AUTHORIZATION;
-SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
CREATE TABLE tp_1_2(i int);
-RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
--- Owner is 'regress_partitions_merge_alice':
+-- Owner is 'regress_partition_merge_alice':
\dt tp_0_1
List of tables
- Schema | Name | Type | Owner
--------------------------+--------+-------+--------------------------------
- partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
(1 row)
--- Owner is 'regress_partitions_merge_bob':
+-- Owner is 'regress_partition_merge_bob':
\dt tp_1_2
List of tables
- Schema | Name | Type | Owner
--------------------------+--------+-------+------------------------------
- partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
(1 row)
-- ERROR: partitions being merged have different owners
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
ERROR: partitions being merged have different owners
DROP TABLE t;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
-DROP ROLE regress_partitions_merge_alice;
-DROP ROLE regress_partitions_merge_bob;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
-- Test for hash partitioned table
CREATE TABLE t (i int) PARTITION BY HASH(i);
CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
@@ -885,6 +874,7 @@ DROP TABLE t;
-- * STORAGE is the same as STORAGE for partitioned table
-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
CREATE TABLE t
(i int NOT NULL,
t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
@@ -928,13 +918,13 @@ CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH
CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
EXECUTE PROCEDURE trigger_function('tp_1_2');
\d+ tp_0_1
- Table "partitions_merge_schema.tp_0_1"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
---------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
- i | integer | | not null | | plain | | tp_0_1.i
- t | text | | | 'default_tp_0_1'::text | main | |
- b | bigint | | not null | | plain | |
- d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
Partition of: t FOR VALUES FROM (0) TO (1)
Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
Check constraints:
@@ -952,13 +942,13 @@ Triggers:
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
\d+ tp_0_1
- Table "partitions_merge_schema.tp_0_1"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
---------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
- i | integer | | not null | | plain | |
- t | text | | | 'default_t'::text | extended | |
- b | bigint | | not null | | plain | |
- d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
Partition of: t FOR VALUES FROM (0) TO (2)
Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
Check constraints:
@@ -983,6 +973,7 @@ SELECT tableoid::regclass, * FROM t ORDER BY b;
DROP TABLE t;
DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
-- Test MERGE PARTITIONS with not valid foreign key constraint
CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index cfb6083e12c..7275c8da1fa 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -111,7 +111,7 @@ EXECUTE get_partition_info('{sales_range}');
SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
-SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
-- Use indexscan for testing indexes
SET enable_seqscan = OFF;
@@ -320,11 +320,11 @@ INSERT INTO sales_range VALUES
(13, 'Gandi', 377, '2022-01-09'),
(14, 'Smith', 510, '2022-05-04');
-SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
-SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
DROP TABLE sales_range;
@@ -413,7 +413,7 @@ ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
-- show partitions with conditions:
EXECUTE get_partition_info('{sales_list}');
-SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid, salesperson_id;
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
-- Use indexscan for testing indexes after merging partitions
SET enable_seqscan = OFF;
@@ -461,7 +461,6 @@ CREATE INDEX tidx ON t(i);
ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
--- Not-null constraint name should be 'tp_1_2_i_not_null'.
\d+ tp_1_2
DROP TABLE t;
@@ -568,61 +567,50 @@ CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
RESET SESSION AUTHORIZATION;
ALTER TABLE t OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
RESET SESSION AUTHORIZATION;
ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --error
RESET SESSION AUTHORIZATION;
ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
SET SESSION AUTHORIZATION regress_partition_merge_bob;
-ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; --ok
RESET SESSION AUTHORIZATION;
DROP TABLE t;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
-DROP ROLE regress_partition_merge_alice;
-DROP ROLE regress_partition_merge_bob;
-
-- Test: we can't merge partitions with different owners
-CREATE ROLE regress_partitions_merge_alice;
-CREATE ROLE regress_partitions_merge_bob;
-GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice;
-GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob;
-SET SESSION AUTHORIZATION regress_partitions_merge_alice;
CREATE TABLE tp_0_1(i int);
-RESET SESSION AUTHORIZATION;
-SET SESSION AUTHORIZATION regress_partitions_merge_bob;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
CREATE TABLE tp_1_2(i int);
-RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
--- Owner is 'regress_partitions_merge_alice':
+-- Owner is 'regress_partition_merge_alice':
\dt tp_0_1
--- Owner is 'regress_partitions_merge_bob':
+-- Owner is 'regress_partition_merge_bob':
\dt tp_1_2
-- ERROR: partitions being merged have different owners
ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
DROP TABLE t;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice;
-REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob;
-DROP ROLE regress_partitions_merge_alice;
-DROP ROLE regress_partitions_merge_bob;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
-- Test for hash partitioned table
@@ -646,6 +634,7 @@ DROP TABLE t;
-- * STORAGE is the same as STORAGE for partitioned table
-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
CREATE TABLE t
(i int NOT NULL,
@@ -704,6 +693,7 @@ INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
SELECT tableoid::regclass, * FROM t ORDER BY b;
DROP TABLE t;
DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
-- Test MERGE PARTITIONS with not valid foreign key constraint
--
2.34.1
Hi!
Thank you for the notes and patch!
1.
ORDER BY regclass seems not stable, see
https://git.postgresql.org/cgit/postgresql.git/commit/
?id=17bcf4f5450430f67b744c225566c9e0e6413e95
some of the SQL tests seem not necessary, so I refactored tests.
Thanks.
Also changed tests for SPLIT PARTITION.
2.
the last part seems intuitive?
"colList = lappend(colList, def);" should be at the end of the for loop?
I agree, it's better.
3.
"-- Not-null constraint name should be 'tp_1_2_i_not_null'.
Comments conflict with the result.
Thanks, this was correct for older versions.
4.
* We reject whole-row variables because the whole point of LIKE is
* that the new table's rowtype might later diverge from the parent's.
...
the above comment needs change, since LIKE is not related to here.
Corrected.
5.
here, we don't need expand_generated_columns_in_expr, the comment also
explained it.
the attached patch is the changes for the above comments.
Applied.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v54-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v54-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 40eba90bdc3559b1aaf0294c84ae1298cd6434c9 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v54 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 120 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 901 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
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/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3613 insertions(+), 25 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..29a0ff5cdb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,14 +1161,108 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use command to merge very big partitions with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal> can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1409,7 +1505,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1949,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 082a3575d6..40aa783a30 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4833,6 +4835,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5268,6 +5274,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5664,6 +5675,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);
@@ -6704,6 +6723,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:
@@ -20193,6 +20214,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20394,23 +20446,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22058,3 +22095,833 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index db43034b9d..6e3b895f72 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17929,6 +17947,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18556,6 +18575,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index afcf54169c..333c51d933 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3510,6 +3513,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3787,6 +3919,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 8b10f2313f..1cf0949fbb 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,6 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3022,6 +3023,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f718..690d259619 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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 9f1e997d81..2040e1c57a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -108,6 +108,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..dc2b9d3445
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..6d9ff02503
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..d818318300
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v54-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v54-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 795628a4ad348346094d362626cbb85e924e494e Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v54 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 102 +-
src/backend/commands/tablecmds.c | 438 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 88 +-
src/backend/partitioning/partbounds.c | 719 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1642 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1149 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4480 insertions(+), 32 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 29a0ff5cdb..0dcdaa05c0 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,78 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into a new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to bound of split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting we have a partition with the
+ same name). Only simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partition is split, any individual objects belonging to this
+ partition, such as constraints or statistics will be dropped. This ccurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, an error will be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires a <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from split partition into them, which can take a long time.
+ So it is not recommended to use command for splitting a small fraction of
+ rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1262,7 +1338,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal> can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1506,7 +1583,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1516,7 +1593,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1949,6 +2027,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 40aa783a30..7bd7842d00 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5279,6 +5286,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5683,6 +5695,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6725,6 +6745,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22925,3 +22947,419 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 6e3b895f72..81f6e5e362 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18016,6 +18050,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18656,6 +18691,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 333c51d933..87469f69ea 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3516,9 +3516,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3528,25 +3530,69 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3623,7 +3669,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3911,7 +3957,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3933,6 +3979,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4363,13 +4423,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4378,9 +4438,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4388,7 +4448,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..c988406b25 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,17 +5033,22 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
+ merge_split
+ ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname)
+ : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5152,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5192,692 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+ bool result = false;
+
+ /*
+ * Need to compare namespaces? One of the schema names may be
+ * undefined, but the schemas may still be equal.
+ */
+ if ((sps->name->schemaname && !sps2->name->schemaname) ||
+ (!sps->name->schemaname && sps2->name->schemaname))
+ {
+ Oid nspid = RangeVarGetCreationNamespace(sps->name);
+ Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid == nspid2)
+ result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
+ }
+ else
+ result = equal(sps->name, sps2->name);
+
+ if (result)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 1cf0949fbb..efe65cf944 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2749,7 +2749,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3012,10 +3012,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3023,6 +3023,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d259619..45b1fa1de8 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0..62043d3bf5 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..5d9e8b0925
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 2040e1c57a..2ad9f97cbe 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..087239a4a1
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..9082e4d10e
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1642 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..6a844eba1e
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1149 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a13e816289..12bfa30c6c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi Dmitry.
On Mon, Sep 1, 2025 at 2:04 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Thank you for the notes and patch!
Some additional notes from me.
1) src/backend/parser/parse_utilcmd.c includes are not alphabetically
ordered here
+#include "partitioning/partdesc.h"
+#include "partitioning/partbounds.h"
2) There is unicode dash in the comment of ATExecMergePartitions() here. I
suggest we should stick to ascii.
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
3) Regarding 17bcf4f545, I see btnamecmp() is collation-aware. Should we
also specify COLLATE "C" every time we do "ORDER BY relname"?
4) This comment sounds misleading. Probably it should say "are contained".
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains
in new
+ * partitions.
+ *
5) Given what latter items say, I think the 1. should say "The DEFAULT
partition must be at most one."
/*
* check_partitions_for_split
*
* Checks new partitions for SPLIT PARTITIONS command:
* 1. DEFAULT partition should be one.
6) Regarding the isolation tests. I see we are exercising INSERTs and
intra-partition UPDATEs. Should we also try some cross-partition UPDATEs?
------
Regards,
Alexander Korotkov
Supabase
On Mon, Sep 15, 2025 at 11:03 AM Alexander Korotkov
<aekorotkov@gmail.com> wrote:
On Mon, Sep 1, 2025 at 2:04 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi!
Thank you for the notes and patch!Some additional notes from me.
1) src/backend/parser/parse_utilcmd.c includes are not alphabetically ordered here +#include "partitioning/partdesc.h" +#include "partitioning/partbounds.h"2) There is unicode dash in the comment of ATExecMergePartitions() here. I suggest we should stick to ascii.
+ /* + * Check ownership of merged partitions — partitions with different + * owners cannot be merged. Also, collect the OIDs of these partitions + * during the check. + */3) Regarding 17bcf4f545, I see btnamecmp() is collation-aware. Should we also specify COLLATE "C" every time we do "ORDER BY relname"?
4) This comment sounds misleading. Probably it should say "are contained".
+/* + * check_parent_values_in_new_partitions + * + * (function for BY LIST partitioning) + * + * Checks that all values of split partition (with Oid partOid) contains in new + * partitions. + *5) Given what latter items say, I think the 1. should say "The DEFAULT partition must be at most one."
/*
* check_partitions_for_split
*
* Checks new partitions for SPLIT PARTITIONS command:
* 1. DEFAULT partition should be one.6) Regarding the isolation tests. I see we are exercising INSERTs and intra-partition UPDATEs. Should we also try some cross-partition UPDATEs?
Additionally, I've made a numerous and small fixes for grammar to the
docs directly to the patchset.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v55-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v55-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From dd9a3d903b6c042ac4012b9347d15613d1d754ac Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v55 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 901 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
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/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3616 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e5..ddb1376a6ea 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c693..5ac1f5c4231 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb8..f069a46a83a 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002f..ef8882cbcdc 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d32..9c7f58a0791 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22099,833 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f8..a46d6c6ea6d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d5..6b3d682f06f 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,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"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec451..60c1036ce88 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b2..3ec033d8d8f 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf5243..f54233499bf 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58b..b1b3315fe54 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a1..90e8cddf8b7 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 65f161f7188..690d2596190 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 00000000000..98446aaab5a
--- /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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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; <waiting ...>
+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 5afae33d370..85415466785 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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 00000000000..dc2b9d3445f
--- /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 is trying to update inserted row and waits until s1 finishes
+# 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/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a341..c403c2f569f 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d4..31e69100a30 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc1..7de5ddb8785 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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 00000000000..6d9ff025036
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae60..2d3f50a43ba 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..d8183183006
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.39.5 (Apple Git-154)
v55-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v55-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From e22bd1bcd9d60237b427d6adc07b41174e03db23 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v55 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 438 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 88 +-
src/backend/partitioning/partbounds.c | 719 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 190 ++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 54 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1642 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1149 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4481 insertions(+), 32 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6ea..c220a1cbc05 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c4231..0fa34443b25 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions' bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9c7f58a0791..355f0ba6c96 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4843,6 +4846,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5283,6 +5290,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5687,6 +5699,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6749,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22929,3 +22951,419 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6d..29416f60fd0 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 6b3d682f06f..dd9d1d1e20a 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,69 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3668,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +3956,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +3978,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4422,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4437,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4447,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce88..c988406b256 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,17 +5033,22 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
+ merge_split
+ ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname)
+ : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5152,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5192,692 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) contains in new
+ * partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+ bool result = false;
+
+ /*
+ * Need to compare namespaces? One of the schema names may be
+ * undefined, but the schemas may still be equal.
+ */
+ if ((sps->name->schemaname && !sps2->name->schemaname) ||
+ (!sps->name->schemaname && sps2->name->schemaname))
+ {
+ Oid nspid = RangeVarGetCreationNamespace(sps->name);
+ Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid == nspid2)
+ result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
+ }
+ else
+ result = equal(sps->name, sps2->name);
+
+ if (result)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd2..3e1689b118c 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8f..a04953e511b 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe54..5c9be8483f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b7..66c8876657e 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 690d2596190..45b1fa1de80 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 5f2ea2e4d0e..62043d3bf5c 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..5d9e8b0925f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,190 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT * FROM tpart;
+ i|t
+--+------
+ 5|text05
+ 1|text01
+15|text15
+25|text25
+35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 85415466785..8503dd801ac 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..087239a4a19
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,54 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT * FROM tpart; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569f..13ccfb74f55 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a30..1e75feaa453 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb8785..17d72e412ff 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..9082e4d10e4
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1642 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43ba..0fb53d486d3 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..6a844eba1ed
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1149 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: "sales_feb_mar_apr2022" is not a partitioned table
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname;
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname;;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname;;
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text;
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, tablespace;
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename, indexname, tablespace;
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname;
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a13e8162890..12bfa30c6c8 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.5 (Apple Git-154)
Hi Alexander.
Thanks for the notes and corrections!
1) src/backend/parser/parse_utilcmd.c includes are not alphabetically
ordered here
+#include "partitioning/partdesc.h"
+#include "partitioning/partbounds.h"
Fixed.
2) There is unicode dash in the comment of ATExecMergePartitions() here.
I suggest we should stick to ascii.
+ /*
+ * Check ownership of merged partitions — partitions with different
+ * owners cannot be merged. Also, collect the OIDs of these partitions
+ * during the check.
+ */
Fixed.
3) Regarding 17bcf4f545, I see btnamecmp() is collation-aware. Should
we also specify COLLATE "C" every time we do "ORDER BY relname"?
Queries changed.
4) This comment sounds misleading. Probably it should say "are contained".
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid)
contains in new
+ * partitions.
+ *
Changed.
5) Given what latter items say, I think the 1. should say "The DEFAULT
partition must be at most one."
/*
* check_partitions_for_split
*
* Checks new partitions for SPLIT PARTITIONS command:
* 1. DEFAULT partition should be one.
Corrected.
6) Regarding the isolation tests. I see we are exercising INSERTs and
intra-partition UPDATEs. Should we also try some cross-partition UPDATEs?
Added simple tests for cross-partition UPDATE.
7) Additionally, I've made a numerous and small fixes for grammar to the
docs directly to the patchset.
Thanks, applied.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v56-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v56-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 85d8682bd67694b563d54f578e50e8fa3b3a6141 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v56 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 901 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3668 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..e79152adac 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22099,833 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
+
+ if (OidIsValid(newPartitionOid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(newPartitionOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v56-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v56-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 8ca8dd140feadd337be230813bda16aca0bdec8d Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v56 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 438 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 88 +-
src/backend/partitioning/partbounds.c | 719 +++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1643 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1150 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4531 insertions(+), 32 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index e79152adac..2e4f4fa3e3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4843,6 +4846,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5283,6 +5290,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5687,6 +5699,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6749,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22929,3 +22951,419 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..e2efe0bf0c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,69 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ Oid splitPartOid;
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3668,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +3956,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +3978,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4422,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4437,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4447,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..0a04d628b6 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,17 +5033,22 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
+ merge_split
+ ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname)
+ : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5152,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5192,692 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = val->location;
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
+ relname),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. DEFAULT partition should be at most one.
+ * 2. New partitions should have different names
+ * (with existing partitions too).
+ * 3. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 4. In case split partition is DEFAULT partition, one of new partitions
+ * should be DEFAULT.
+ * 5. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
+ * partition can be defined as one of new partition.
+ * 7. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart;
+ int default_index = -1;
+ int i,
+ j;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ /*
+ * Make array new_parts with new partitions except DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ i = 0;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index >= 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(pstate, sps->name->location));
+ default_index = i;
+ }
+ else
+ {
+ new_parts[nparts++] = sps;
+ }
+ i++;
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index < 0)
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
+ parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
+ }
+ else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(partlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
+ parser_errposition(pstate, spsDef->name->location));
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ createDefaultPart = (default_index >= 0);
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+
+ /* Check: new partitions should have different names. */
+ for (j = i + 1; j < nparts; j++)
+ {
+ SinglePartitionSpec *sps2 = new_parts[j];
+ bool result = false;
+
+ /*
+ * Need to compare namespaces? One of the schema names may be
+ * undefined, but the schemas may still be equal.
+ */
+ if ((sps->name->schemaname && !sps2->name->schemaname) ||
+ (!sps->name->schemaname && sps2->name->schemaname))
+ {
+ Oid nspid = RangeVarGetCreationNamespace(sps->name);
+ Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid == nspid2)
+ result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
+ }
+ else
+ result = equal(sps->name, sps2->name);
+
+ if (result)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("name \"%s\" is already used", sps2->name->relname),
+ parser_errposition(pstate, sps2->name->location));
+ }
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..3e1689b118 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13707,3 +13707,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7ba7d88791..726e418193 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..886e5e0ab7
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1643 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..7da5377bbd
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1150 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Tue, Sep 16, 2025 at 6:11 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
7) Additionally, I've made a numerous and small fixes for grammar to the
docs directly to the patchset.
v56-0002, SPLIT PARTITION check_partitions_for_split is way too overwhelming.
Similar to transformPartitionCmdForMerge, we can put some error handling code
to transformPartitionCmdForSplit.
please check the attached refactoring.
in v56-0001
+ Oid newPartitionOid = InvalidOid;
+
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ if (mergingPartitionOid == existingRelid)
+ {
+ newPartitionOid = mergingPartitionOid;
+ break;
+ }
+ }
can simplified to
if (list_member_oid(mergingPartitions, existingRelid))
newPartitionOid = existingRelid;
Attachments:
v56-0001-refactor-v56-check_partitions_for_split.no-cfbotapplication/octet-stream; name=v56-0001-refactor-v56-check_partitions_for_split.no-cfbotDownload
From 2c9cf178e36befbad30ce9030b899bb27f79ad4d Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Tue, 16 Sep 2025 16:42:17 +0800
Subject: [PATCH v56 1/1] refactor v56 check_partitions_for_split
move some of error handling in check_partitions_for_split to
transformPartitionCmdForSplit.
---
src/backend/parser/parse_utilcmd.c | 112 ++++++++++++-
src/backend/partitioning/partbounds.c | 157 +++++-------------
src/test/regress/expected/partition_split.out | 15 +-
3 files changed, 161 insertions(+), 123 deletions(-)
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e2efe0bf0c9..1b7a270ca51 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3565,10 +3565,24 @@ static void
transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
{
Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
Oid splitPartOid;
+ Oid defaultPartOid;
+ int i = 0;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
/* Transform partition bounds for all partitions in the list: */
- foreach_node(SinglePartitionSpec, sps, partcmd->partlist)
+ foreach_node(SinglePartitionSpec, sps, splitlist)
{
cxt->partbound = NULL;
transformPartitionCmd(cxt, sps->bound);
@@ -3587,8 +3601,102 @@ transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
checkPartition(parent, splitPartOid, false);
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ default_index = foreach_current_index(sps);
+ i++;
+ }
+
+ if (i > 1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition exists,
+ * then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("New partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
/* Then we should check partitions with transformed bounds. */
- check_partitions_for_split(parent, splitPartOid, partcmd->partlist, cxt->pstate);
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
}
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 0a04d628b6a..168d92bdf8c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5446,7 +5446,7 @@ check_partition_bounds_for_split_list(Relation parent, char *relname,
*/
foreach_node(Const, val, spec->listdatums)
{
- overlap_location = val->location;
+ overlap_location = exprLocation((Node *) val);
if (!val->constisnull)
{
int offset;
@@ -5469,8 +5469,9 @@ check_partition_bounds_for_split_list(Relation parent, char *relname,
else
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partition \"%s\" cannot have this value because split partition does not have",
- relname),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
parser_errposition(pstate, overlap_location));
}
else if (partition_bound_accepts_nulls(boundinfo))
@@ -5485,8 +5486,9 @@ check_partition_bounds_for_split_list(Relation parent, char *relname,
else
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partition \"%s\" cannot have NULL value because split partition does not have",
- relname),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
parser_errposition(pstate, overlap_location));
}
@@ -5639,19 +5641,12 @@ check_parent_values_in_new_partitions(Relation parent,
* check_partitions_for_split
*
* Checks new partitions for SPLIT PARTITIONS command:
- * 1. DEFAULT partition should be at most one.
- * 2. New partitions should have different names
- * (with existing partitions too).
- * 3. Bounds of new partitions should not overlap with new and existing
+ * 1. Bounds of new partitions should not overlap with new and existing
* partitions.
- * 4. In case split partition is DEFAULT partition, one of new partitions
- * should be DEFAULT.
- * 5. In case new partitions or existing partitions contains DEFAULT
+ * 2. In case new partitions or existing partitions contains DEFAULT
* partition, new partitions can have any bounds inside split
* partition bound (can be spaces between partitions bounds).
- * 6. In case partitioned table does not have DEFAULT partition, DEFAULT
- * partition can be defined as one of new partition.
- * 7. In case new partitions not contains DEFAULT partition and
+ * 3. In case new partitions not contains DEFAULT partition and
* partitioned table does not have DEFAULT partition the following
* should be true: sum bounds of new partitions should be equal
* to bound of split partition.
@@ -5671,59 +5666,49 @@ check_partitions_for_split(Relation parent,
char strategy;
Oid defaultPartOid;
bool isSplitPartDefault;
- bool createDefaultPart;
+ bool createDefaultPart = false;
int default_index = -1;
- int i,
- j;
+ int i;
SinglePartitionSpec **new_parts;
SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition
+ */
int nparts = 0;
key = RelationGetPartitionKey(parent);
strategy = get_partition_strategy(key);
- switch (strategy)
- {
- case PARTITION_STRATEGY_LIST:
- case PARTITION_STRATEGY_RANGE:
- {
- /*
- * Make array new_parts with new partitions except DEFAULT
- * partition.
- */
- new_parts = (SinglePartitionSpec **)
- palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
- i = 0;
- foreach_node(SinglePartitionSpec, sps, partlist)
- {
- if (sps->bound->is_default)
- {
- if (default_index >= 0)
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("DEFAULT partition should be one"),
- parser_errposition(pstate, sps->name->location));
- default_index = i;
- }
- else
- {
- new_parts[nparts++] = sps;
- }
- i++;
- }
- }
- break;
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
- case PARTITION_STRATEGY_HASH:
- ereport(ERROR,
- errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("partition of hash-partitioned table cannot be split"));
- break;
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
- default:
- elog(ERROR, "unexpected partition strategy: %d",
- (int) key->strategy);
- break;
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
}
if (strategy == PARTITION_STRATEGY_RANGE)
@@ -5761,33 +5746,6 @@ check_partitions_for_split(Relation parent,
pfree(lower_bounds);
}
- defaultPartOid =
- get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
-
- /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
- isSplitPartDefault = (defaultPartOid == splitPartOid);
-
- if (isSplitPartDefault && default_index < 0)
- {
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("one partition in the list should be DEFAULT because split partition is DEFAULT"),
- parser_errposition(pstate, ((SinglePartitionSpec *) linitial(partlist))->name->location));
- }
- else if (!isSplitPartDefault && (default_index >= 0) && OidIsValid(defaultPartOid))
- {
- SinglePartitionSpec *spsDef =
- (SinglePartitionSpec *) list_nth(partlist, default_index);
-
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partition cannot be DEFAULT because DEFAULT partition already exists"),
- parser_errposition(pstate, spsDef->name->location));
- }
-
- /* Indicator that the DEFAULT partition will be created. */
- createDefaultPart = (default_index >= 0);
-
for (i = 0; i < nparts; i++)
{
SinglePartitionSpec *sps = new_parts[i];
@@ -5833,35 +5791,6 @@ check_partitions_for_split(Relation parent,
pstate);
spsPrev = sps;
-
- /* Check: new partitions should have different names. */
- for (j = i + 1; j < nparts; j++)
- {
- SinglePartitionSpec *sps2 = new_parts[j];
- bool result = false;
-
- /*
- * Need to compare namespaces? One of the schema names may be
- * undefined, but the schemas may still be equal.
- */
- if ((sps->name->schemaname && !sps2->name->schemaname) ||
- (!sps->name->schemaname && sps2->name->schemaname))
- {
- Oid nspid = RangeVarGetCreationNamespace(sps->name);
- Oid nspid2 = RangeVarGetCreationNamespace(sps2->name);
-
- if (nspid == nspid2)
- result = (strcmp(sps->name->relname, sps2->name->relname) == 0);
- }
- else
- result = equal(sps->name, sps2->name);
-
- if (result)
- ereport(ERROR,
- errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("name \"%s\" is already used", sps2->name->relname),
- parser_errposition(pstate, sps2->name->location));
- }
}
if (strategy == PARTITION_STRATEGY_LIST)
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 886e5e0ab7e..e328838474f 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -62,7 +62,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb_mar_apr2022" is already used
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
^
-- ERROR: name "sales_feb2022" is already used
@@ -70,7 +70,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" is already used
+ERROR: partition with name "sales_feb2022" is already used
LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
^
-- ERROR: name "sales_feb2022" is already used
@@ -78,7 +78,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: name "sales_feb2022" is already used
+ERROR: partition with name "sales_feb2022" is already used
LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
^
-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
@@ -509,9 +509,10 @@ ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
-ERROR: one partition in the list should be DEFAULT because split partition is DEFAULT
+ERROR: can not split DEFAULT partition "sales_others"
LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
@@ -915,7 +916,7 @@ ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partition "sales_west" cannot have NULL value because split partition does not have
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
^
-- ERROR: new partition "sales_west" cannot have this value because split partition does not have
@@ -923,7 +924,7 @@ ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partition "sales_west" cannot have this value because split partition does not have
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
^
-- ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
@@ -932,7 +933,7 @@ ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
PARTITION sales_others2 DEFAULT);
-ERROR: new partition cannot be DEFAULT because DEFAULT partition already exists
+ERROR: New partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
LINE 5: PARTITION sales_others2 DEFAULT);
^
DROP TABLE sales_list;
--
2.34.1
Hi, Jiah He!
Thank you for the patch!
1.
can simplified to
if (list_member_oid(mergingPartitions, existingRelid))
newPartitionOid = existingRelid;
Applied (with small additional changes).
2. Patch v56-0001-refactor-v56-check_partitions_for_split.no-cfbot
applied with cosmetic changes.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v57-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v57-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 479dec781d853ea749d4914543d0177f7fe39333 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v57 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..9aaa0c67fb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22099,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v57-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v57-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 2f909471e929715add09855a20a735400a741981 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v57 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 438 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 648 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1645 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1151 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4569 insertions(+), 32 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9aaa0c67fb..d61b73e9dd 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4843,6 +4846,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5283,6 +5290,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5687,6 +5699,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6749,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22940,419 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ char relname[NAMEDATALEN];
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ strlcpy(relname, sps->name->relname, NAMEDATALEN);
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..95d44fa71c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..a72cd7f428 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
+ * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool merge_split,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,17 +5033,22 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
+ merge_split
+ ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname)
+ : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ merge_split
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5152,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5192,621 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int overlap_location = -1;
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ overlap_location = val->location;
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, overlap_location));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, datum->location));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+
+ /*
+ * Lower bound of "spec" should be equal (or greater than or equal
+ * in case defaultPart=true) to lower bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval < 0)
+ {
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+
+ /*
+ * Upper bound of "spec" should be equal (or less than or equal in
+ * case defaultPart=true) to upper bound of split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ else
+ {
+ if (cmpval > 0)
+ {
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
+ relname),
+ parser_errposition(pstate, datum->location));
+ }
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0408a95941..c165fc6012 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13709,3 +13709,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7ba7d88791..726e418193 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..7bafd93e2f
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1645 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..72853e423a
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1151 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+CREATE ROLE regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+DROP ROLE regress_partition_split_alice;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Wed, Sep 17, 2025 at 6:08 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
2. Patch v56-0001-refactor-v56-check_partitions_for_split.no-cfbot
applied with cosmetic changes.
hi.
check_two_partitions_bounds_range
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
merge_split
? errmsg("can not merge partition \"%s\" together with
partition \"%s\"",
second_name->relname, first_name->relname)
: errmsg("can not split to partition \"%s\" together
with partition \"%s\"",
second_name->relname, first_name->relname),
errdetail("lower bound of partition \"%s\" is not
equal to the upper bound of partition \"%s\"",
second_name->relname, first_name->relname),
merge_split
? errhint("ALTER TABLE ... MERGE PARTITIONS requires
the partition bounds to be adjacent.")
: errhint("ALTER TABLE ... SPLIT PARTITIONS requires
the partition bounds to be adjacent."),
parser_errposition(pstate, datum->location));
This is too much...., also bad for translation, so I refactored this.
I also refactored check_partition_bounds_for_split_range.
In ATExecSplitPartition,
"char relname[NAMEDATALEN];" is not necessary?
Attachments:
v57-0001-refactor-for-v57.no-cfbotapplication/octet-stream; name=v57-0001-refactor-for-v57.no-cfbotDownload
From 27bc6581d5a74ecb130c322baae90fd7c09f36c6 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 17 Sep 2025 15:31:55 +0800
Subject: [PATCH v57 1/1] refactor for v57
mainly refactoring these function check_two_partitions_bounds_range and
check_partition_bounds_for_split_range.
---
src/backend/commands/tablecmds.c | 5 +-
src/backend/partitioning/partbounds.c | 147 +++++++++---------
src/test/regress/expected/partition_split.out | 12 +-
3 files changed, 82 insertions(+), 82 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d61b73e9dd1..9a52a36edba 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -23216,7 +23216,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Relation splitRel;
Oid splitRelOid;
- char relname[NAMEDATALEN];
ListCell *listptr,
*listptr2;
bool isSameName = false;
@@ -23243,8 +23242,6 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Oid existingRelid;
- strlcpy(relname, sps->name->relname, NAMEDATALEN);
-
/* Look up existing relation by new partition name. */
RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
@@ -23258,7 +23255,7 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
else if (OidIsValid(existingRelid))
ereport(ERROR,
errcode(ERRCODE_DUPLICATE_TABLE),
- errmsg("relation \"%s\" already exists", relname));
+ errmsg("relation \"%s\" already exists", sps->name->relname));
}
/* Detach split partition. */
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index a72cd7f4282..9ac00d2ff44 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5000,8 +5000,8 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
* second_name: name of second partition
* second_bound: bound of second partition
* defaultPart: true if one of new partitions is DEFAULT
- * merge_or_split: true indicate the opration is "ALTER TABLE ... MERGE PARTITIONS"
- * false indicate the opration is "ALTER TABLE ... SPLIT PARTITIONS".
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5011,7 +5011,7 @@ check_two_partitions_bounds_range(Relation parent,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
bool defaultPart,
- bool merge_split,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5037,19 +5037,24 @@ check_two_partitions_bounds_range(Relation parent,
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- merge_split
- ? errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname)
- : errmsg("can not split to partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- merge_split
- ? errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.")
- : errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5212,7 +5217,6 @@ check_partitions_not_overlap_list(Relation parent,
ParseState *pstate)
{
PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
- int overlap_location = -1;
int i,
j;
SinglePartitionSpec *sps1,
@@ -5238,12 +5242,11 @@ check_partitions_not_overlap_list(Relation parent,
{
Const *val = (Const *) lfirst(list_head(overlap));
- overlap_location = val->location;
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
sps1->name->relname, sps2->name->relname),
- parser_errposition(pstate, overlap_location));
+ parser_errposition(pstate, exprLocation((Node *) val)));
}
}
}
@@ -5315,7 +5318,7 @@ check_partition_bounds_for_split_range(Relation parent,
errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
get_range_partbound_string(spec->lowerdatums),
get_range_partbound_string(spec->upperdatums)),
- parser_errposition(pstate, datum->location));
+ parser_errposition(pstate, exprLocation((Node *)datum)));
}
/* Need to check first and last partitions (from set of new partitions) */
@@ -5335,35 +5338,33 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
lower->datums, lower->kind,
true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
/*
- * Lower bound of "spec" should be equal (or greater than or equal
- * in case defaultPart=true) to lower bound of split partition.
- */
- if (!defaultPart)
- {
- if (cmpval != 0)
- {
- datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition",
- relname),
- parser_errposition(pstate, datum->location));
- }
- }
- else
- {
- if (cmpval < 0)
- {
- datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("lower bound of partition \"%s\" is less than lower bound of split partition",
- relname),
- parser_errposition(pstate, datum->location));
- }
- }
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to be
+ * greater than that of the split partition.
+ */
+ if (!defaultPart && cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *)datum)));
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *)datum)));
}
else
{
@@ -5376,35 +5377,33 @@ check_partition_bounds_for_split_range(Relation parent,
key->partcollation,
upper->datums, upper->kind,
false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
/*
- * Upper bound of "spec" should be equal (or less than or equal in
- * case defaultPart=true) to upper bound of split partition.
- */
- if (!defaultPart)
- {
- if (cmpval != 0)
- {
- datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition",
- relname),
- parser_errposition(pstate, datum->location));
- }
- }
- else
- {
- if (cmpval > 0)
- {
- datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition",
- relname),
- parser_errposition(pstate, datum->location));
- }
- }
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to be
+ * less than that of the split partition.
+ */
+ if (!defaultPart && cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *)datum)));
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *)datum)));
}
}
}
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 7bafd93e2f6..c933332facb 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -53,9 +53,10 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -94,9 +95,10 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
-ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -114,9 +116,10 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
-ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- Check the source partition not in the search path
SET search_path = partition_split_schema2, public;
ALTER TABLE partition_split_schema.sales_range
@@ -1511,9 +1514,10 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
-ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
DROP TABLE sales_range;
-- Test for split partition properties:
-- * STATISTICS is empty
--
2.34.1
On Sep 17, 2025, at 06:08, Dmitry Koval <d.koval@postgrespro.ru> wrote:
Postgres Professional: http://postgrespro.com<v57-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch><v57-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch>
1 - 0001
```
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * The behavior must specified as DROP_RESTRICT.
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
```
Nit: “when you need delete” => “when you need to delete"
“Must specified” => “must be specified"
“We want delete” => “we want to delete"
2 - 0001
```
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
```
This function looks only performing read-only checks, why do we need RowExclusiveLock? Is AccessShareLock good enough?
3 - 0001
```
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
```
AT_MergePartitions, AT_DetachPartitionFinalize and AT_DetachPartition do the same thing, why don’t combine them together?
I see the previous code combine multiple cases if they do the same thing right in this switch:
case AT_EnableRule: /* ENABLE/DISABLE RULE variants */
case AT_EnableAlwaysRule:
case AT_EnableReplicaRule:
case AT_DisableRule:
case AT_AddOf: /* OF */
case AT_DropOf: /* NOT OF */
case AT_EnableRowSecurity:
case AT_DisableRowSecurity:
case AT_ForceRowSecurity:
case AT_NoForceRowSecurity:
ATSimplePermissions(cmd->subtype, rel,
ATT_TABLE | ATT_PARTITIONED_TABLE);
/* These commands never recurse */
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
4 - 0001
```
+ /* Attach a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
```
I think the comment can be removed as the function name has clearly described what it is doing.
5 - 0001
```
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
```
I think bound can be const: const PartitionBoundSpec *bound, to indicate read-only on bound.
Of course, you need to also update StorePartitionBound() to make bound also const, as StorePartitionBound() doesn’t update bound as well.
I tried to make them const in my local, and the build passed.
6 - 0001
```
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
```
Here seems an extra empty line is added.
6 - 0001
```
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
```
Nit: an unneeded empty line.
7 - 0001
```
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
```
Why this local variable starts with a capital character “C”?
8 - 0001
```
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
```
In this function, “parent_rel->rd_rel” is used in many places, maybe we can cache it to a local variable.
9 - 0001
```
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
```
This comment is quite confusing. Can you rewording to something like:
```
/* Create a source tuple slot for the partition being merged. */
```
10 - 0001
```
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
```
Based on the comment of “foreach”, deleting cell while interacting is unsafe.
And nit: “need process” => “need to process"
11 - 0001
```
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
```
Should it be “all merging partitions”?
12 - 0001
```
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
```
I think the first two “if” can be combined. We are trying to check If “partRel” is a partition, when a relation is a partition, its relkind is “r” and “relispartition” is true. Instead, “xx is not a table” is a quite confusing message. I would suggest:
```
if (partRel->rd_rel->relkind != RELKIND_RELATION || !partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
```
13 - 0001
```
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
```
We can immediately close the table, as data is stored in partRel already, we don’t have to defer table close.
14 - 0002
```
@@ -5283,6 +5290,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
```
Same as comment 3.
14 - 0002
```
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
```
Same as comment 10.
15 - 0002
```
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
```
For move rows, the logic of merge partitions and split partition are quite similar. Only difference is that merge partitions takes a fixed dest partition, but split partition use a logic to determine target partition. Maybe we can add a common function to reduce the duplicate code.
Best regards,
--
Chao Li (Evan)
HighGo Software Co., Ltd.
https://www.highgo.com/
On Wed, Sep 17, 2025 at 3:35 PM jian he <jian.universality@gmail.com> wrote:
On Wed, Sep 17, 2025 at 6:08 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
2. Patch v56-0001-refactor-v56-check_partitions_for_split.no-cfbot
applied with cosmetic changes.
In the previous thread
(/messages/by-id/CACJufxGWCVf5r9kE-z6MyR2b+wkaU15Q5m2tKz4cvBhYX3-x1g@mail.gmail.com)
I refactored src/test/regress/sql/partition_merge.sql permission related tests.
attached is refactor for src/test/regress/sql/partition_split.sql
permission related tests.
I grouped the permission-related tests together and
removed unnecessary CREATE ROLE commands.
overall readability improved, i think.
Attachments:
v57-0001-partition_split.sql-test-refactor-based-on-v57.no-cfbotapplication/octet-stream; name=v57-0001-partition_split.sql-test-refactor-based-on-v57.no-cfbotDownload
From 1c0e3c54d9725fda3498826cccf4ea74d8e9743e Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 17 Sep 2025 16:20:16 +0800
Subject: [PATCH v57 1/1] partition_split.sql test refactor based on v57
changes in src/test/regress/sql/partition_split.sql:
* make permission related tests together.
* reduce unnecessarily 'CREATE ROLE', 'DROP ROLE', only one 'CREATE ROLE', 'DROP
ROLE' is enough in here.
---
src/test/regress/expected/partition_split.out | 70 +++++++---------
src/test/regress/sql/partition_split.sql | 80 ++++++++-----------
2 files changed, 65 insertions(+), 85 deletions(-)
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 7bafd93e2f6..cb481fa491e 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -1322,39 +1322,6 @@ ORDER BY c.relname COLLATE "C";
DROP TABLE t;
DROP ACCESS METHOD partition_split_heap;
--- Test permission checks. The user needs to own the parent table and the
--- the partition to split to do the split.
-CREATE ROLE regress_partition_split_alice;
-CREATE ROLE regress_partition_split_bob;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_split_alice;
-CREATE TABLE t (i int) PARTITION BY RANGE (i);
-CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-ERROR: must be owner of table t
-RESET SESSION AUTHORIZATION;
-ALTER TABLE t OWNER TO regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-ERROR: must be owner of table tp_0_2
-RESET SESSION AUTHORIZATION;
-ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-RESET SESSION AUTHORIZATION;
-DROP TABLE t;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
-DROP ROLE regress_partition_split_alice;
-DROP ROLE regress_partition_split_bob;
-- Split partition of a temporary table when one of the partitions after
-- split has the same name as the partition being split
CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
@@ -1422,9 +1389,36 @@ Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
-- Test: owner of new partitions should be the same as owner of split partition
-CREATE ROLE regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
SET SESSION AUTHORIZATION regress_partition_split_alice;
CREATE TABLE tp_0_2(i int);
@@ -1457,12 +1451,8 @@ ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
(1 row)
DROP TABLE t;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
-DROP ROLE regress_partition_split_alice;
-- Test: index of new partitions should be created with same owner as split
-- partition
-CREATE ROLE regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
SET SESSION AUTHORIZATION regress_partition_split_alice;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
@@ -1487,7 +1477,9 @@ NOTICE: you are running me as regress_partition_split_alice
DROP TABLE t;
DROP FUNCTION run_me(integer);
REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
-- Test for hash partitioned table
CREATE TABLE t (i int) PARTITION BY HASH(i);
CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 72853e423a7..eefb488253e 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -905,43 +905,6 @@ ORDER BY c.relname COLLATE "C";
DROP TABLE t;
DROP ACCESS METHOD partition_split_heap;
--- Test permission checks. The user needs to own the parent table and the
--- the partition to split to do the split.
-CREATE ROLE regress_partition_split_alice;
-CREATE ROLE regress_partition_split_bob;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
-
-SET SESSION AUTHORIZATION regress_partition_split_alice;
-CREATE TABLE t (i int) PARTITION BY RANGE (i);
-CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
-
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-RESET SESSION AUTHORIZATION;
-
-ALTER TABLE t OWNER TO regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-RESET SESSION AUTHORIZATION;
-
-ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
-SET SESSION AUTHORIZATION regress_partition_split_bob;
-ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
- (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
- PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
-RESET SESSION AUTHORIZATION;
-
-DROP TABLE t;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
-DROP ROLE regress_partition_split_alice;
-DROP ROLE regress_partition_split_bob;
-
-- Split partition of a temporary table when one of the partitions after
-- split has the same name as the partition being split
CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
@@ -971,11 +934,40 @@ ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
\d+ t_bigint_01_10
DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
-- Test: owner of new partitions should be the same as owner of split partition
-CREATE ROLE regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
-
CREATE TABLE t (i int) PARTITION BY RANGE (i);
SET SESSION AUTHORIZATION regress_partition_split_alice;
@@ -996,15 +988,9 @@ ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
\dt tp_1_2
DROP TABLE t;
-REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
-DROP ROLE regress_partition_split_alice;
-
-- Test: index of new partitions should be created with same owner as split
-- partition
-CREATE ROLE regress_partition_split_alice;
-GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
-
SET SESSION AUTHORIZATION regress_partition_split_alice;
CREATE TABLE t (i int) PARTITION BY RANGE (i);
CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
@@ -1029,7 +1015,9 @@ DROP TABLE t;
DROP FUNCTION run_me(integer);
REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
-- Test for hash partitioned table
CREATE TABLE t (i int) PARTITION BY HASH(i);
--
2.34.1
Hi, Jiah He!
1. v57-0001-refactor-for-v57.no-cfbot
Thanks, the patch make the code clearer.
I added small correction in function check_partition_bounds_for_split_range.
Before the patch, the old code contained the condition:
---------------------------------
if (!defaultPart)
{
if (cmpval != 0)
...
}
else
{
if (cmpval < 0)
...
}
---------------------------------
The patch changed this to:
---------------------------------
if (!defaultPart && cmpval != 0)
...
else if (cmpval < 0)
...
---------------------------------
This change is not equivalent to the old code, so it replaced with:
---------------------------------
if (!defaultPart)
{
if (cmpval != 0)
....
}
else if (cmpval < 0)
...
---------------------------------
2. v57-0001-partition_split.sql-test-refactor-based-on-v57.no-cfbot
I grouped the permission-related tests together and
removed unnecessary CREATE ROLE commands.
overall readability improved, i think.
Applied (I agree, readability improved).
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v58-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v58-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 479dec781d853ea749d4914543d0177f7fe39333 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v58 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..f069a46a83 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need delete some objects later. See comments in
+ * performDeletion too.
+ * The behavior must specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want delete later (ie, the given object
+ * plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..9aaa0c67fb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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 a new partition to the partitioned table. */
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22099,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *Constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ Constraints = lappend(Constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, Constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_rel->rd_rel->relam != InvalidOid) ? parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_rel->rd_rel->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create tuple slot for new partition. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merged partitions */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v58-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v58-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 5fb86e12f654bc1dfb47808ca4968f591b091dfa Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v58 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 435 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 663 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1645 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1143 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4568 insertions(+), 37 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9aaa0c67fb..9a52a36edb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4843,6 +4846,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = AccessExclusiveLock;
break;
+ case AT_SplitPartition:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5283,6 +5290,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
/* No command-specific prep needed */
pass = AT_PASS_MISC;
break;
+ case AT_SplitPartition:
+ ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5687,6 +5699,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6749,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22940,416 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create tuple slot for new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need process this pc->partRel so delete the ALTER TABLE queue
+ * of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..95d44fa71c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..daeb29d2c3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,621 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0408a95941..c165fc6012 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13709,3 +13709,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7ba7d88791..726e418193 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..f845343d82
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1645 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ed326b2076
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1143 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi Chao Li!
Thanks for reporting the issues!
1.
Nit: "when you need delete" => "when you need to delete"
"Must specified" => "must be specified"
"We want delete" => "we want to delete"
Replaced.
2.
+ depRel = table_open(DependRelationId, RowExclusiveLock);
This function looks only performing read-only checks, why do we need
RowExclusiveLock? Is AccessShareLock good enough?
performDeletionCheck function is not required for the SPLIT/MERGE
PARTITION(S) functionality.
Its main goal is perform a preliminary check to determine whether it's
safe to drop split partition before we actually do so later.
For this purpose, it would be better if the lock is the same as in the
performDeletion function.
3.
AT_MergePartitions, AT_DetachPartitionFinalize and AT_DetachPartition
do the same thing, why don't combine them together?
I think AT_MergePartitions and AT_SplitPartitions can be combine.
But I prefer not to change of other conditions as possible
(AT_DetachPartitionFinalize, AT_DetachPartition, etc.) to avoid rebase
conflicts.
Changed.
4.
+ /* Attach a new partition to the partitioned table. */ + attachPartitionTable(wqueue, rel, attachrel, cmd->bound); I think the comment can be removed as the function name has clearly
described what it is doing.
Deleted.
5.
+static void +attachPartitionTable(List **wqueue, Relation rel, Relation attachrel,
PartitionBoundSpec *bound)
I think bound can be const: const PartitionBoundSpec *bound, to
indicate read-only on bound.
Of course, you need to also update StorePartitionBound() to make bound
also const ...
I agree, this correction could be done.
But I think it's better to change the argument of the
StorePartitionBound function in a separate commit, since this fix is not
related to SPLIT/MERGE PARTITION(S).
And then we can change attachPartitionTable function.
6.
Nit: an unneeded empty line.
Empty lines (this and similar ones) removed.
7.
+ case CONSTR_CHECK: + + /* + * We already expanded virtual expression in + * createTableConstraints. + */ Nit: an unneeded empty line.
This line was added by pgindent...
8.
+ List *Constraints = NIL;
Why this local variable starts with a capital character "C"?
I think it was because of my carelessness. Renamed.
9.
+ /* Look up the access method for new relation. */ + relamId = (parent_rel->rd_rel->relam != InvalidOid) ?
parent_rel->rd_rel->relam : HEAP_TABLE_AM_OID;
In this function, "parent_rel->rd_rel" is used in many places, maybe
we can cache it to a local variable.```
Changed.
10.
+ /* Create tuple slot for new partition. */ + srcslot = table_slot_create(mergingPartition, NULL); This comment is quite confusing. Can you rewording to something like: /* Create a source tuple slot for the partition being merged. */
Renamed.
11.
Based on the comment of "foreach", deleting cell while interacting is
unsafe.
And nit: "need process" => "need to process"
Corrected.
12.
+ /* Detach all merged partitions */ + foreach_oid(mergingPartitionOid, mergingPartitions) Should it be "all merging partitions"?
Corrected.
13.
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
...
+ if (!partRel->rd_rel->relispartition)
...
I think the first two "if" can be combined. We are trying to check If
"partRel" is a partition, when a relation is a partition, its relkind
is "r" and "relispartition" is true. Instead, "xx is not a table" is
a quite confusing message. ...
if (partRel->rd_rel->relkind != RELKIND_RELATION ||
!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
...
Probably, in this case we will generate a strange error if relkind='f'
(RELKIND_FOREIGN_TABLE) since it's a partition, but error message will
be "... is not a partition ...".
Perhaps we should change the error message from "... is not a table" to
"... is not a ordinary table"?
See comment:
#define RELKIND_RELATION 'r' /* ordinary table */
14.
+checkPartition(Relation rel, Oid partRelOid) ... + partRel = table_open(partRelOid, NoLock); We can immediately close the table, as data is stored in partRel already, we don't have to defer table close.
It can be done, but I think this violates the style used in PostgreSQL
(for example, [1]https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1197, [2]https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1590, ...).
15.
For move rows, the logic of merge partitions and split partition are
quite similar. Only difference is that merge partitions takes a fixed
dest partition, but split partition use a logic to determine target
partition. Maybe we can add a common function to reduce the duplicate
code.
The problem is that MERGE PARTITIONS is planned to be optimized further
to use the merging partition with the maximum number of rows as the new
merged partition (we minimize the number of moved rows).
This will complicate the logic, and we will have to revert to situation
with different code for SPLIT and MERGE.
Links.
------
[1]: https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1197
https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1197
[2]: https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1590
https://github.com/postgres/postgres/blob/b0cc0a71e0a0a760f54c72edb8cd000e4555442b/src/backend/commands/cluster.c#L1590
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v59-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v59-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 780cf46d791c74e4e9b51ba1dba5dea98e976f1f Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v59 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..d554f77bec 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22098,823 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v59-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v59-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 51a0e19003910947c1311dda10843b6af5c1073f Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v59 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 663 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1645 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1143 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4563 insertions(+), 37 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d554f77bec..16075391f4 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5279,6 +5283,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5687,6 +5692,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6742,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22933,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..95d44fa71c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..daeb29d2c3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,621 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ /*
+ * Calculate intersection between values of two partitions.
+ */
+ overlap = list_intersection(sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0408a95941..c165fc6012 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13709,3 +13709,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7ba7d88791..726e418193 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..f845343d82
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1645 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ed326b2076
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1143 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi. about v59.
check_partitions_not_overlap_list
overlap = list_intersection(sps1->bound->listdatums,
sps2->bound->listdatums);
if (list_length(overlap) > 0)
{
Const *val = (Const *) lfirst(list_head(overlap));
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("new partition \"%s\" would overlap
with another new partition \"%s\"",
sps1->name->relname, sps2->name->relname),
parser_errposition(pstate, exprLocation((Node *) val)));
}
list_intersection seems not right, how can we be sure it deals with
collation correctly?
It failed to deal with numeric special value (0.0).
demo:
CREATE TABLE t (a numeric) PARTITION BY LIST (a);
CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
ALTER TABLE t SPLIT PARTITION t1 INTO
(PARTITION x FOR VALUES in ('0'),
PARTITION x1 FOR VALUES IN ('0.0', '1'));
I’ll think about the solution later; for now, I just wanted to point
out this problem.
Hi, Jiah He!
Thanks!
list_intersection seems not right, how can we be sure it deals with
collation correctly?
list_intersection function replaced by new partitions_lists_intersection
function.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v60-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v60-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 9ea622fe11ba2f7b39ae1cf62b1e35adb3af3cc2 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v60 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..d554f77bec 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22098,823 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86a236bd58..b1b3315fe5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v60-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v60-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 4566f832d0bf80d367390fd25f57013f881cd4a5 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v60 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 717 ++++++-
src/backend/utils/adt/ruleutils.c | 18 +
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
src/include/utils/ruleutils.h | 2 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1656 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1152 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
22 files changed, 4637 insertions(+), 37 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d554f77bec..16075391f4 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5279,6 +5283,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5687,6 +5692,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6742,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22933,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..95d44fa71c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITIONS".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..5f2ee6e02a 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,675 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_lists_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains all the cells that are in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ */
+static List *
+partitions_lists_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result;
+ const ListCell *cell;
+
+ if (list1 == NIL || list2 == NIL)
+ return false;
+
+ result = NIL;
+ foreach(cell, list1)
+ {
+ Const *val1 = lfirst_node(Const, cell);
+
+ if (!val1->constisnull)
+ {
+ const ListCell *cell2;
+
+ foreach(cell2, list2)
+ {
+ Const *val2 = lfirst_node(Const, cell2);
+
+ if (val2->constisnull)
+ continue;
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, lfirst(cell));
+ break;
+ }
+ }
+ }
+ else if (list_member(list2, lfirst(cell)))
+ result = lappend(result, lfirst(cell));
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_lists_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) lfirst(list_head(overlap));
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... MERGE PARTITIONS"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ bool searchNull = false;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ {
+ found = false;
+ searchNull = true;
+ }
+ }
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ if (!searchNull)
+
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITIONS command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * list: list of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0408a95941..c165fc6012 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13709,3 +13709,21 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b1b3315fe5..5c9be8483f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 7ba7d88791..726e418193 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,4 +54,6 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
+extern char *get_list_partvalue_string(Const *val);
+
#endif /* RULEUTILS_H */
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..8c11c6c309
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1656 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+ERROR: relation "sales_jan_feb2022" does not exist
+LINE 1: SELECT * FROM sales_jan_feb2022;
+ ^
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+ attname | attidentity | attgenerated
+------------------+-------------+--------------
+ salesperson_id | a |
+ salesperson_name | |
+(2 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions do not have value NULL but split partition does
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions do not have value 'Kyiv' but split partition does
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITIONS can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..20342c4541
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1152 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+--ERROR: relation "sales_jan_feb2022" does not exist
+SELECT * FROM sales_jan_feb2022;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- Split partition has identity column:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
+-- New partitions have identity-columns:
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
+SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list
+(salesperson_id INT,
+ salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions do not have value NULL but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions do not have value 'Kyiv' but split partition does
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Additional tests for error messages
+CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Sat, Sep 20, 2025 at 4:06 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi, Jiah He!
Thanks!
list_intersection seems not right, how can we be sure it deals with
collation correctly?list_intersection function replaced by new partitions_lists_intersection
function.
hi, more about v60.
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
duplicated CommandCounterIncrement call?
+
+/*
+ * get_list_partvalue_string
+ * A C string representation of one list partition value
+ */
+char *
+get_list_partvalue_string(Const *val)
+{
+ deparse_context context;
+ StringInfo buf = makeStringInfo();
+
+ memset(&context, 0, sizeof(deparse_context));
+ context.buf = buf;
+
+ get_const_expr(val, &context, -1);
+
+ return buf->data;
+}
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions do not have value %s but split partition does",
+ searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
get_list_partvalue_string seems not quite right, because it won't print Const
node collation info. However, sometimes we do really need to print the
collation, i think.
give that we can do:
CREATE TABLE x(a text collate "C") PARTITION BY LIST (a collate
case_insensitive);
we can simply call deparse_expression. so I removed the
get_list_partvalue_string.
partitions_lists_intersection
will get all the common Const nodes in two PartitionBoundSpec->listdatums.
but that's expensive, and we only need the first common Const location
for error reporting, so I refactored it too.
I propose to change the function name check_partitions_not_overlap_list
to check_list_partitions_overlap,
what do you think?
I also heavily refactor the test again.
(arrange some error check test code together, combine several tests together,
remove/reduce unnecessary tests).
For example, the below code can be merged together to make it more readable.
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE
attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY
attnum;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE
attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY
attnum;
SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE
attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY
attnum;
please check the attached v60 refactor for SPLIT PARTITION.
Attachments:
v60-0001-refactor-v60.no-cfbotapplication/octet-stream; name=v60-0001-refactor-v60.no-cfbotDownload
From e0b1f82bb0ce10e07db4316d1d81cdaeac6b29f2 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Mon, 22 Sep 2025 15:44:22 +0800
Subject: [PATCH v60 1/1] refactor v60
mainly refactor:
partitions_lists_intersection
check_parent_values_in_new_partitions
regress test
---
src/backend/partitioning/partbounds.c | 131 ++++++------
src/backend/utils/adt/ruleutils.c | 18 --
src/include/utils/ruleutils.h | 2 -
src/test/regress/expected/partition_split.out | 188 +++++++-----------
src/test/regress/sql/partition_split.sql | 104 ++++------
5 files changed, 183 insertions(+), 260 deletions(-)
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 5f2ee6e02a7..8115caacc6a 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5199,55 +5199,66 @@ calculate_partition_bound_for_merge(Relation parent,
}
/*
- * partitions_lists_intersection
+ * partitions_listdatum_intersection
*
* (function for BY LIST partitioning)
*
* Function compares lists of values for different partitions.
- * Return a list that contains all the cells that are in both list1 and
+ * Return a list that contains *one* cell that are in both list1 and
* list2. The returned list is freshly allocated via palloc(), but the
* cells themselves point to the same objects as the cells of the
* input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
*/
static List *
-partitions_lists_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
- const List *list1, const List *list2)
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
{
- List *result;
- const ListCell *cell;
+ List *result = NIL;
+ bool isnull1 = false;
+ bool isnull2 = false;
if (list1 == NIL || list2 == NIL)
- return false;
+ return result;
- result = NIL;
- foreach(cell, list1)
+ foreach_node(Const, val1, list1)
{
- Const *val1 = lfirst_node(Const, cell);
-
- if (!val1->constisnull)
+ if (val1->constisnull)
{
- const ListCell *cell2;
-
- foreach(cell2, list2)
+ if (isnull2)
{
- Const *val2 = lfirst_node(Const, cell2);
-
- if (val2->constisnull)
- continue;
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull1 = true;
+ continue;
+ }
- /* Compare two datums values. */
- if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
- partcollation[0],
- val1->constvalue,
- val2->constvalue)) == 0)
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
{
- result = lappend(result, lfirst(cell));
- break;
+ result = lappend(result, val1);
+ return result;
}
+ isnull2 = true;
+ continue;
+ }
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
}
}
- else if (list_member(list2, lfirst(cell)))
- result = lappend(result, lfirst(cell));
}
return result;
@@ -5288,13 +5299,13 @@ check_partitions_not_overlap_list(Relation parent,
{
sps2 = parts[j];
- overlap = partitions_lists_intersection(&key->partsupfunc[0],
- key->partcollation,
- sps1->bound->listdatums,
- sps2->bound->listdatums);
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
if (list_length(overlap) > 0)
{
- Const *val = (Const *) lfirst(list_head(overlap));
+ Const *val = (Const *) linitial_node(Const, overlap);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
@@ -5410,7 +5421,7 @@ check_partition_bounds_for_split_range(Relation parent,
relname,
get_rel_name(splitPartOid)),
errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
- "ALTER TABLE ... MERGE PARTITIONS"),
+ "ALTER TABLE ... SPLIT PARTITIONS"),
parser_errposition(pstate, exprLocation((Node *) datum)));
}
else if (cmpval < 0)
@@ -5420,7 +5431,7 @@ check_partition_bounds_for_split_range(Relation parent,
relname,
get_rel_name(splitPartOid)),
errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
- "ALTER TABLE ... MERGE PARTITIONS"),
+ "ALTER TABLE ... SPLIT PARTITIONS"),
parser_errposition(pstate, exprLocation((Node *) datum)));
}
else
@@ -5452,7 +5463,7 @@ check_partition_bounds_for_split_range(Relation parent,
relname,
get_rel_name(splitPartOid)),
errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
- "ALTER TABLE ... MERGE PARTITIONS"),
+ "ALTER TABLE ... SPLIT PARTITIONS"),
parser_errposition(pstate, exprLocation((Node *) datum)));
}
else if (cmpval > 0)
@@ -5462,7 +5473,7 @@ check_partition_bounds_for_split_range(Relation parent,
relname,
get_rel_name(splitPartOid)),
errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
- "ALTER TABLE ... MERGE PARTITIONS"),
+ "ALTER TABLE ... SPLIT PARTITIONS"),
parser_errposition(pstate, exprLocation((Node *) datum)));
}
}
@@ -5632,7 +5643,6 @@ check_parent_values_in_new_partitions(Relation parent,
PartitionBoundInfo boundinfo = partdesc->boundinfo;
int i;
bool found = true;
- bool searchNull = false;
Datum datum = PointerGetDatum(NULL);
Assert(key->strategy == PARTITION_STRATEGY_LIST);
@@ -5646,12 +5656,18 @@ check_parent_values_in_new_partitions(Relation parent,
{
if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
key->partcollation, parts, nparts, datum, true))
- {
found = false;
- searchNull = true;
- }
}
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITIONS"));
+
/*
* Search all values of split partition with partOid in PartitionDesc of
* partitioned table.
@@ -5675,24 +5691,25 @@ check_parent_values_in_new_partitions(Relation parent,
{
Const *notFoundVal;
- if (!searchNull)
-
- /*
- * Make Const for getting string representation of not found
- * value.
- */
- notFoundVal = makeConst(key->parttypid[0],
- key->parttypmod[0],
- key->parttypcoll[0],
- key->parttyplen[0],
- datum,
- false, /* isnull */
- key->parttypbyval[0]);
+ /*
+ * Make Const for getting string representation of not found
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
ereport(ERROR,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("new partitions do not have value %s but split partition does",
- searchNull ? "NULL" : get_list_partvalue_string(notFoundVal)));
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITIONS"));
}
}
@@ -5712,7 +5729,7 @@ check_parent_values_in_new_partitions(Relation parent,
*
* parent: partitioned table
* splitPartOid: split partition Oid
- * list: list of new partitions
+ * partlist: list of new partitions after partition split
* pstate: pointer to ParseState struct for determine error position
*/
void
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c165fc6012e..0408a95941d 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -13709,21 +13709,3 @@ get_range_partbound_string(List *bound_datums)
return buf->data;
}
-
-/*
- * get_list_partvalue_string
- * A C string representation of one list partition value
- */
-char *
-get_list_partvalue_string(Const *val)
-{
- deparse_context context;
- StringInfo buf = makeStringInfo();
-
- memset(&context, 0, sizeof(deparse_context));
- context.buf = buf;
-
- get_const_expr(val, &context, -1);
-
- return buf->data;
-}
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index 726e418193f..7ba7d887914 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -54,6 +54,4 @@ extern char *get_range_partbound_string(List *bound_datums);
extern char *pg_get_statisticsobjdef_string(Oid statextid);
-extern char *get_list_partvalue_string(Const *val);
-
#endif /* RULEUTILS_H */
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 8c11c6c309c..70294286f38 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -11,7 +11,7 @@ SET search_path = partition_split_schema, public;
--
-- Test for error codes
--
-CREATE TABLE sales_range (salesperson_id int, salesperson_name varchar(30), sales_amount int, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -57,7 +57,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
@@ -100,7 +100,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -122,7 +122,7 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
^
-HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- Check the source partition not in the search path
SET search_path = partition_split_schema2, public;
ALTER TABLE partition_split_schema.sales_range
@@ -132,13 +132,11 @@ SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
SET search_path = partition_split_schema, public;
\d+ sales_range
- Partitioned table "partition_split_schema.sales_range"
- Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
-------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
- salesperson_id | integer | | | | plain | |
- salesperson_name | character varying(30) | | | | extended | |
- sales_amount | integer | | | | plain | |
- sales_date | date | | | | plain | |
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
Partition key: RANGE (sales_date)
Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
@@ -147,6 +145,21 @@ Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022')
DROP TABLE sales_range;
DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
--
-- Add rows into partitioned table then split partition
--
@@ -200,6 +213,21 @@ CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sale
CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -220,21 +248,6 @@ Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022')
sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
sales_others DEFAULT
-INSERT INTO sales_range VALUES
- (1, 'May', 1000, '2022-01-31'),
- (2, 'Smirnoff', 500, '2022-02-10'),
- (3, 'Ford', 2000, '2022-04-30'),
- (4, 'Ivanov', 750, '2022-04-13'),
- (5, 'Deev', 250, '2022-04-07'),
- (6, 'Poirot', 150, '2022-02-11'),
- (7, 'Li', 175, '2022-03-08'),
- (8, 'Ericsson', 185, '2022-02-23'),
- (9, 'Muller', 250, '2022-03-11'),
- (10, 'Halder', 350, '2022-01-28'),
- (11, 'Trump', 380, '2022-04-06'),
- (12, 'Plato', 350, '2022-03-19'),
- (13, 'Gandi', 377, '2022-01-09'),
- (14, 'Smith', 510, '2022-05-04');
SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
---------------------------------------+----------------+------------------+--------------+------------
@@ -315,11 +328,6 @@ SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text C
sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
(11 rows)
---ERROR: relation "sales_jan_feb2022" does not exist
-SELECT * FROM sales_jan_feb2022;
-ERROR: relation "sales_jan_feb2022" does not exist
-LINE 1: SELECT * FROM sales_jan_feb2022;
- ^
DROP TABLE sales_date CASCADE;
--
-- Test: split DEFAULT partition; use an index on partition key; check index after split
@@ -460,7 +468,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2021 (lower bound)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
@@ -532,7 +540,7 @@ CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
@@ -710,28 +718,6 @@ CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
--- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
(PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
@@ -746,41 +732,26 @@ SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text
salespeople4_5 | 4 | Ford
(4 rows)
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
--- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
-
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
- attname | attidentity | attgenerated
-------------------+-------------+--------------
- salesperson_id | a |
- salesperson_name | |
-(2 rows)
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
DROP TABLE salespeople CASCADE;
--
@@ -892,13 +863,7 @@ DROP TABLE sales_range;
--
-- Test: specific errors for BY LIST partitioning
--
-CREATE TABLE sales_list
-(salesperson_id INT,
- salesperson_name VARCHAR(30),
- sales_state VARCHAR(20),
- sales_amount INT,
- sales_date DATE)
-PARTITION BY LIST (sales_state);
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
@@ -960,13 +925,7 @@ DROP TABLE t;
-- * new partitions do not have NULL value, which split partition has.
-- * new partitions do not have a value that split partition has.
--
-CREATE TABLE sales_list
-(salesperson_id INT,
- salesperson_name VARCHAR(30),
- sales_state VARCHAR(20),
- sales_amount INT,
- sales_date DATE)
-PARTITION BY LIST (sales_state);
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
-- ERROR: new partitions do not have value NULL but split partition does
@@ -974,13 +933,15 @@ ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
-ERROR: new partitions do not have value NULL but split partition does
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR: new partitions do not have value 'Kyiv' but split partition does
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
-ERROR: new partitions do not have value 'Kyiv' but split partition does
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-- ERROR DEFAULT partition should be one
ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
(PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
@@ -1511,21 +1472,6 @@ ALTER TABLE t SPLIT PARTITION tp1 INTO
(PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
ERROR: list of new partitions should contain at least two partitions
DROP TABLE t;
--- Additional tests for error messages
-CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
--- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
--- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
- PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
-ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
-LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
- ^
-HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-DROP TABLE sales_range;
-- Test for split partition properties:
-- * STATISTICS is empty
-- * COMMENT is empty
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 20342c4541d..8b0f67c5379 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -14,7 +14,7 @@ SET search_path = partition_split_schema, public;
--
-- Test for error codes
--
-CREATE TABLE sales_range (salesperson_id int, salesperson_name varchar(30), sales_amount int, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
@@ -116,6 +116,20 @@ SET search_path = partition_split_schema, public;
DROP TABLE sales_range;
DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
--
-- Add rows into partitioned table then split partition
--
@@ -156,6 +170,22 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
-- Split partition, also check schema qualification of new partitions
ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
(PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
@@ -163,22 +193,6 @@ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
\d+ sales_range
-INSERT INTO sales_range VALUES
- (1, 'May', 1000, '2022-01-31'),
- (2, 'Smirnoff', 500, '2022-02-10'),
- (3, 'Ford', 2000, '2022-04-30'),
- (4, 'Ivanov', 750, '2022-04-13'),
- (5, 'Deev', 250, '2022-04-07'),
- (6, 'Poirot', 150, '2022-02-11'),
- (7, 'Li', 175, '2022-03-08'),
- (8, 'Ericsson', 185, '2022-02-23'),
- (9, 'Muller', 250, '2022-03-11'),
- (10, 'Halder', 350, '2022-01-28'),
- (11, 'Trump', 380, '2022-04-06'),
- (12, 'Plato', 350, '2022-03-19'),
- (13, 'Gandi', 377, '2022-01-09'),
- (14, 'Smith', 510, '2022-05-04');
-
SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
DROP TABLE sales_range CASCADE;
@@ -222,9 +236,6 @@ INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VAL
SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
---ERROR: relation "sales_jan_feb2022" does not exist
-SELECT * FROM sales_jan_feb2022;
-
DROP TABLE sales_date CASCADE;
--
@@ -284,7 +295,7 @@ DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2021 (lower bound)
@@ -341,7 +352,7 @@ CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
(PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20210101) TO (20210201),
+ PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
PARTITION sales_others DEFAULT);
@@ -489,11 +500,6 @@ ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (
INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
--- Split partition has identity column:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_5'::regclass::oid ORDER BY attnum;
-
ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
(PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
@@ -503,12 +509,13 @@ INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople'::regclass::oid ORDER BY attnum;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople1_2'::regclass::oid ORDER BY attnum;
--- New partitions have identity-columns:
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople2_3'::regclass::oid ORDER BY attnum;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople3_4'::regclass::oid ORDER BY attnum;
-SELECT attname, attidentity, attgenerated FROM pg_attribute WHERE attnum > 0 AND attrelid = 'salespeople4_5'::regclass::oid ORDER BY attnum;
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
DROP TABLE salespeople CASCADE;
@@ -595,13 +602,7 @@ DROP TABLE sales_range;
--
-- Test: specific errors for BY LIST partitioning
--
-CREATE TABLE sales_list
-(salesperson_id INT,
- salesperson_name VARCHAR(30),
- sales_state VARCHAR(20),
- sales_amount INT,
- sales_date DATE)
-PARTITION BY LIST (sales_state);
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
@@ -654,13 +655,7 @@ DROP TABLE t;
-- * new partitions do not have NULL value, which split partition has.
-- * new partitions do not have a value that split partition has.
--
-CREATE TABLE sales_list
-(salesperson_id INT,
- salesperson_name VARCHAR(30),
- sales_state VARCHAR(20),
- sales_amount INT,
- sales_date DATE)
-PARTITION BY LIST (sales_state);
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
@@ -1048,21 +1043,6 @@ ALTER TABLE t SPLIT PARTITION tp1 INTO
DROP TABLE t;
--- Additional tests for error messages
-CREATE TABLE sales_range (salesperson_id int, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
-
--- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
--- HINT: ALTER TABLE ... MERGE PARTITIONS require combined bounds of new partitions must exactly match the bound of the split partition
-ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
- (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
- PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
- PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
-
-DROP TABLE sales_range;
-
-
-- Test for split partition properties:
-- * STATISTICS is empty
-- * COMMENT is empty
--
2.34.1
Hi, Jiah He!
1.
duplicated CommandCounterIncrement call?
Probably this duplication is necessary to rename partition correctly ...
2.
we can simply call deparse_expression. so I removed the
get_list_partvalue_string.
I agree. This looks better.
3.
partitions_lists_intersection
will get all the common Const nodes in two
PartitionBoundSpec->listdatums.
but that's expensive, and we only need the first common Const location
for error reporting, so I refactored it too.
Ok. If a universal function is needed in the future,
partitions_lists_intersection can be modified.
4.
I also heavily refactor the test again....
Thanks! Applied with minor changes.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v61-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v61-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 4f221f145b3089e9f204de55361713e7b8a08565 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v61 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 3be2e051d3..d554f77bec 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22098,823 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 9fd48acb1f..a46d6c6ea6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -755,7 +755,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2367,6 +2367,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2381,6 +2382,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2394,6 +2396,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2410,6 +2427,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17930,6 +17948,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18557,6 +18576,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6b20a4404b..3ec033d8d8 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,6 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,6 +3024,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4ed14fc5b7..38bf045f24 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,13 +964,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2473,6 +2476,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v61-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v61-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From ec02dc6bf25e08735d167830932fd798b9aba669 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v61 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 103 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 733 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 21 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1604 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4563 insertions(+), 37 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..d8e8383b07 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1161,6 +1165,79 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported. Bounds of new
+ partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ If the split partition is a <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ In case one of the new partitions is <literal>DEFAULT</literal>,
+ new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can
+ have spaces between partitions bounds. If the partitioned table does not
+ have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
+ partition can be defined as one of the new partitions.
+ </para>
+ <para>
+ In case new partitions do not contain a <literal>DEFAULT</literal>
+ partition, the following must be true: sum bounds of new partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... should
+ be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, ... can have
+ the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting a <literal>DEFAULT</literal>
+ partition: we split it, but after splitting, we have a partition with the
+ same name). Only a simple, non-partitioned partition can be split.
+ </para>
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partitions.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When a partition is split, any individual objects belonging to this
+ partition, such as constraints or the statistics will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to define these objects.
+ </para>
+ <para>
+ If a split partition has some objects dependent on it, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1264,7 +1341,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1586,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1596,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2030,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index d554f77bec..16075391f4 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5279,6 +5283,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5687,6 +5692,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6742,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22933,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a46d6c6ea6..29416f60fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -257,6 +257,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -640,6 +641,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -770,7 +773,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2357,6 +2360,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2401,6 +2421,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18017,6 +18051,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18657,6 +18692,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..d09ce12749 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..6e7c7478c3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,691 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that are in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+ bool isnull1 = false;
+ bool isnull2 = false;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ if (val1->constisnull)
+ {
+ if (isnull2)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull1 = true;
+ continue;
+ }
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull2 = true;
+ continue;
+ }
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make Const for getting string representation of not found value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3ec033d8d8..a04953e511 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2750,7 +2750,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3013,10 +3013,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3024,6 +3024,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 38bf045f24..db8d2377c7 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -963,17 +963,29 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
+ RangeVar *name; /* name of partition to
+ * attach/detach/merge/split */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+ List *partlist; /* list of partitions to be split/merged, used
+ * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2488,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..250123bd92
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1604 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..ffd95a4306
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
+ PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
+ PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e90af5b2ad..f0016c598d 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2777,6 +2777,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2843,6 +2844,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare upper
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
I am confused by the above comments "we compare upper bound only".
some of the function partition_rbound_cmp can be replaced by marco
compare_range_bounds,
for example in check_two_partitions_bounds_range we can use
compare_range_bounds instead of partition_rbound_cmp
not sure if it's worth it or not.
doc:
<varlistentry id="sql-altertable-split-partition">
should come after
<varlistentry id="sql-altertable-merge-partitions">
I’ve refactored the SPLIT PARTITION docs quite a bit—let me know if they make
sense.
Also tweaked the regression tests a little again.
Attachments:
v61-0001-refactoring-based-on-v61.no-cfbotapplication/octet-stream; name=v61-0001-refactoring-based-on-v61.no-cfbotDownload
From 789e0fa790918ecb845bac634bc25708a3008617 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 1 Oct 2025 12:59:09 +0800
Subject: [PATCH v61 1/1] refactoring based on v61
---
doc/src/sgml/ref/alter_table.sgml | 160 ++++++++++--------
src/include/nodes/parsenodes.h | 20 ++-
src/test/regress/expected/partition_split.out | 82 ++++-----
src/test/regress/sql/partition_split.sql | 54 +++---
4 files changed, 163 insertions(+), 153 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index d8e8383b071..05fbc27309a 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1165,79 +1165,6 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
- <varlistentry id="sql-altertable-split-partition">
- <term><literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }, PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])</literal></term>
-
- <listitem>
- <para>
- This form splits a single partition of the target table into new
- partitions. Hash-partitioned target table is not supported. Bounds of new
- partitions should not overlap with new and existing partitions
- (except <replaceable class="parameter">partition_name</replaceable>).
- If the split partition is a <literal>DEFAULT</literal> partition, one of
- the new partitions must be <literal>DEFAULT</literal>.
- In case one of the new partitions is <literal>DEFAULT</literal>,
- new partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... can
- have spaces between partitions bounds. If the partitioned table does not
- have a <literal>DEFAULT</literal> partition, the <literal>DEFAULT</literal>
- partition can be defined as one of the new partitions.
- </para>
- <para>
- In case new partitions do not contain a <literal>DEFAULT</literal>
- partition, the following must be true: sum bounds of new partitions
- <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... should
- be equal to the bound of the split partition <replaceable class="parameter">partition_name</replaceable>.
- One of the new partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, ... can have
- the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
- (this is suitable in case of splitting a <literal>DEFAULT</literal>
- partition: we split it, but after splitting, we have a partition with the
- same name). Only a simple, non-partitioned partition can be split.
- </para>
- <para>
- New partitions will have the same owner as the parent partition.
- It is the user's responsibility to setup <acronym>ACL</acronym> on new
- partitions.
- </para>
- <para>
- The indexes and identity are created later, after moving the data
- into the new partitions.
- Extended statistics aren't copied from the parent table, for consistency with
- <command>CREATE TABLE PARTITION OF</command>.
- New partitions will inherit the same table access method, persistence
- type, and tablespace as the parent table.
- </para>
- <para>
- When a partition is split, any individual objects belonging to this
- partition, such as constraints or the statistics will be dropped. This occurs
- because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
- as the template to define these objects.
- </para>
- <para>
- If a split partition has some objects dependent on it, the command can
- not be done (<literal>CASCADE</literal> is not used, and an error will
- be returned).
- </para>
- <note>
- <para>
- Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
- the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
- lock on the table being split.
- </para>
- </note>
- <note>
- <para>
- <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
- moves data from the split partition into them, which can take a long
- time. So it is not recommended to use the command for splitting a
- small fraction of rows out of a very big partition.
- </para>
- </note>
- </listitem>
- </varlistentry>
-
<varlistentry id="sql-altertable-merge-partitions">
<term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
@@ -1334,6 +1261,91 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have <literal>DEFAULT</literal> partition,
+ <literal>DEFAULT</literal> partition can be defined as one of the new partitions.
+ </para>
+
+ <para>
+ Bounds of new partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bound of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition remains with the same
+ name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partitions. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to reconstruct these objects later.
+ Eventually we will drop the split partition (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE SPLIT PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1341,7 +1353,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- <literal>SPLIT PARTITION</literal>, and <literal>MERGE PARTITIONS</literal>
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 28414109242..03afa65ed81 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -982,11 +982,21 @@ typedef struct SinglePartitionSpec
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to
- * attach/detach/merge/split */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be split/merged, used
- * in ALTER TABLE SPLIT/MERGE PARTITION(S) */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in
+ * ALTER TABLE MERGE PARTITOINS and ALTER TABLE SPLIT PARTITOINS.
+ * For merge partitions, partlist is a list of RangeVar; For split
+ * partition, it is a list of SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index 250123bd928..e68baf71daf 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -440,108 +440,96 @@ SELECT * FROM sales_others where sales_date > '2022-01-01';
(1 row)
RESET enable_seqscan;
-SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
schemaname | tablename | indexname | tablespace | indexdef
------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
-(1 row)
-
-SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
- schemaname | tablename | indexname | tablespace | indexdef
-------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
-(1 row)
-
-SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
- schemaname | tablename | indexname | tablespace | indexdef
-------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
- partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
-(1 row)
-
-SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
- schemaname | tablename | indexname | tablespace | indexdef
-------------------------+--------------+------------------------------+------------+-----------------------------------------------------------------------------------------------------------
- partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
-(1 row)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2021 (lower bound)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
-LINE 3: PARTITION sales_error FOR VALUES FROM (20211230) TO (2022...
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
^
DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
-- sales_error intersects with sales_feb2022 (upper bound)
-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
-LINE 4: PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20...
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
^
DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
-- sales_error intersects with sales_dec2021 (inside bound)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
-LINE 3: PARTITION sales_error FOR VALUES FROM (20211210) TO (2021...
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
^
DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
-- sales_error intersects with sales_dec2021 (exactly the same bounds)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
-LINE 3: PARTITION sales_error FOR VALUES FROM (20211201) TO (2022...
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
^
DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
-- ERROR: can not split DEFAULT partition "sales_others"
-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
ERROR: can not split DEFAULT partition "sales_others"
-LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20...
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
^
HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
--
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index ffd95a43065..0e79c036ea9 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -285,75 +285,75 @@ SELECT * FROM sales_others where sales_date > '2022-01-01';
RESET enable_seqscan;
-SELECT * FROM pg_indexes WHERE tablename = 'sales_feb2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
-SELECT * FROM pg_indexes WHERE tablename = 'sales_mar2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
-SELECT * FROM pg_indexes WHERE tablename = 'sales_apr2022' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
-SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
DROP TABLE sales_range CASCADE;
--
-- Test: some cases for splitting DEFAULT partition (different bounds)
--
-CREATE TABLE sales_range (salesperson_id INT, sales_amount INT) PARTITION BY RANGE (sales_amount);
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- sales_error intersects with sales_dec2021 (lower bound)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211230) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
-- sales_error intersects with sales_feb2022 (upper bound)
-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20220101) TO (20220202),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
-- sales_error intersects with sales_dec2021 (inside bound)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211210) TO (20211220),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
-- sales_error intersects with sales_dec2021 (exactly the same bounds)
-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_error FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
-- ERROR: can not split DEFAULT partition "sales_others"
-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_jan2022 FOR VALUES FROM (20220101) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301));
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20220110) TO (20220120),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
-CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date INT) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
- (PARTITION sales_dec2021 FOR VALUES FROM (20211201) TO (20220101),
- PARTITION sales_noerror FOR VALUES FROM (20220101) TO (20220201),
- PARTITION sales_feb2022 FOR VALUES FROM (20220201) TO (20220301),
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
PARTITION sales_others DEFAULT);
DROP TABLE sales_range;
--
2.34.1
Hi, Jiah He!
Thanks!
1.
I am confused by the above comments "we compare upper bound only".
Replaced: upper -> lower.
2.
some of the function partition_rbound_cmp can be replaced by marco
compare_range_bounds,
for example in check_two_partitions_bounds_range we can use
compare_range_bounds instead of partition_rbound_cmp
not sure if it's worth it or not.
I think would be better keep partition_rbound_cmp in this function
because we should use "false" instead of "second_lower->kind".
3.
<varlistentry id="sql-altertable-split-partition">
should come after
<varlistentry id="sql-altertable-merge-partitions">
I’ve refactored the SPLIT PARTITION docs quite a bit—let me know if
they make sense.
Also tweaked the regression tests a little again.
Applied.
Unfortunately, I don't know English well enough to spot the inaccuracies
in doc.
It looks good in translation.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v62-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v62-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 677a37d0783e548ff418ac7b3fd836c88922919b Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v62 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 124 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 890 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3657 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 8867da6c69..5ac1f5c423 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1159,18 +1161,114 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of the partitions
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ must be adjacent in order to be merged. Otherwise, an error will be
+ raised. The resulting combined range will be the new partition bound
+ for the partition <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for all partitions-
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>, [...]
+ can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ The new partition <replaceable class="parameter">partition_name</replaceable>
+ can have the same name as one of the merged partitions. Only simple,
+ non-partitioned partitions can be merged.
+ </para>
+ <para>
+ If merged partitions have different owners, an error will be generated.
+ The owner of the merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ new partition.
+ </para>
+ <para>
+ The indexes and identity are created later, after moving the data
+ into the new partition.
+ Extended statistics aren't copied from the parent table, for consistency with
+ <command>CREATE TABLE PARTITION OF</command>.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the parent table.
+ </para>
+ <para>
+ When partitions are merged, any individual objects belonging to those
+ partitions, such as constraints or statistics, will be dropped. This occurs
+ because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
+ template to define these objects.
+ </para>
+ <para>
+ If merged partitions have some objects dependent on them, the command can
+ not be done (<literal>CASCADE</literal> is not used, and an error will
+ be returned).
+ </para>
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1409,7 +1507,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1842,6 +1951,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index fc89352b66..7053387b2e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -741,6 +741,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4837,6 +4839,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5272,6 +5278,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5668,6 +5679,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);
@@ -6708,6 +6727,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:
@@ -20197,6 +20218,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20398,23 +20450,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22062,3 +22098,823 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot convert whole-row table reference"),
+ errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".",
+ NameStr(attribute->attname),
+ RelationGetRelationName(parent_rel)));
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for LIKE
+ * and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f1def67ac7..23ed9af6e7 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -756,7 +756,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2368,6 +2368,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2382,6 +2383,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2395,6 +2397,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2411,6 +2428,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17944,6 +17962,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18571,6 +18590,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 6176741d20..ec9b2b1fca 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2760,6 +2760,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3033,6 +3034,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ac0e02a1db..c2cd3043e1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,13 +965,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2475,6 +2478,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 a4af3f717a..90e8cddf8b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -337,6 +337,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index fbffc67ae6..2d3f50a43b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v62-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v62-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 6cbd40074c9275c88f5025d73cefb9359424933a Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v62 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 115 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 733 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 33 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4574 insertions(+), 38 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5ac1f5c423..05fbc27309 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1257,6 +1261,91 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have <literal>DEFAULT</literal> partition,
+ <literal>DEFAULT</literal> partition can be defined as one of the new partitions.
+ </para>
+
+ <para>
+ Bounds of new partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bound of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition remains with the same
+ name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partitions. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to reconstruct these objects later.
+ Eventually we will drop the split partition (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE SPLIT PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1264,7 +1353,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1508,7 +1598,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1518,7 +1608,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1951,6 +2042,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 7053387b2e..2455f680fa 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -743,6 +743,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4840,6 +4843,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5279,6 +5283,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5687,6 +5692,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6729,6 +6742,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22918,3 +22933,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 23ed9af6e7..ca8719fef9 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -258,6 +258,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
struct SelectLimit *selectlimit;
@@ -641,6 +642,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -771,7 +774,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2358,6 +2361,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2402,6 +2422,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18031,6 +18065,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18671,6 +18706,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..d09ce12749 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..f1de7ced76 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,691 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that are in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+ bool isnull1 = false;
+ bool isnull2 = false;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ if (val1->constisnull)
+ {
+ if (isnull2)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull1 = true;
+ continue;
+ }
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull2 = true;
+ continue;
+ }
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make Const for getting string representation of not found value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare lower
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ec9b2b1fca..fccbb04a0c 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2760,7 +2760,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3023,10 +3023,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3034,6 +3034,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index c2cd3043e1..03afa65ed8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -964,17 +964,39 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in
+ * ALTER TABLE MERGE PARTITOINS and ALTER TABLE SPLIT PARTITOINS.
+ * For merge partitions, partlist is a list of RangeVar; For split
+ * partition, it is a list of SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2478,6 +2500,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 90e8cddf8b..66c8876657 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -421,6 +421,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..e68baf71da
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2d3f50a43b..0fb53d486d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..0e79c036ea
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 37f26f6c6b..912aaa88b5 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2780,6 +2780,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2846,6 +2847,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
hi.
please check the attach doc refactor for v62-0001.
if (found_whole_row && attribute->attgenerated != '\0')
ereport(ERROR,
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert whole-row table reference"),
errdetail("Generation expression for column
\"%s\" contains a whole-row reference to table \"%s\".",
NameStr(attribute->attname),
RelationGetRelationName(parent_rel)));
here ereport should be elog(ERROR...).
since this error should be unreachable. see check_nested_generated, cookDefault.
/*
* For the moment we have to reject whole-row variables (as for LIKE
* and inheritances).
*/
if (found_whole_row)
elog(ERROR, "Constraint \"%s\" contains a whole-row
reference to table \"%s\".",
ccname,
RelationGetRelationName(parent_rel));
"table \"%s\".", we don't need that extra period.
"(as for LIKE and inheritances)":
I think you meant, “CREATE TABLE LIKE and table inheritance reject
whole-row check constraint, here we will do the same”.
maybe change to ""(as for CREATE TABLE LIKE and inheritances)".
Overall, I found v62-0001 code makes sense to me.
Attachments:
v62-0001-doc-refactor-alter-table-merge-partitions-v62.no-cfbotapplication/octet-stream; name=v62-0001-doc-refactor-alter-table-merge-partitions-v62.no-cfbotDownload
From 9851f5d28535907f6add8c02f25e513c620ddacf Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Wed, 15 Oct 2025 19:23:50 +0800
Subject: [PATCH v62 1/1] doc refactor alter table merge partitions v62
doc changes.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
---
doc/src/sgml/ref/alter_table.sgml | 77 ++++++++++++++++---------------
1 file changed, 39 insertions(+), 38 deletions(-)
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 30dd5ef8466..f8dc2a10209 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1166,32 +1166,34 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<para>
This form merges several partitions of the target table into a new partition.
Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
If the <literal>DEFAULT</literal> partition is not in the
- list of partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ list of merged partitions:
<itemizedlist>
<listitem>
<para>
- For range-partitioned tables, the ranges of the partitions
- <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, [...]
- must be adjacent in order to be merged. Otherwise, an error will be
- raised. The resulting combined range will be the new partition bound
- for the partition <replaceable class="parameter">partition_name</replaceable>.
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
<listitem>
<para>
For list-partitioned tables, the partition bounds of
- <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, [...]
- are combined to form the new partition bound for
+ merged partitions are combined to form the new partition bound for
<replaceable class="parameter">partition_name</replaceable>.
</para>
</listitem>
</itemizedlist>
- If the <literal>DEFAULT</literal> partition is in the list of partitions <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable> [, ...]:
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
<itemizedlist>
<listitem>
<para>
@@ -1201,42 +1203,41 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
<listitem>
<para>
- The partition bound specifications for all partitions-
- <replaceable class="parameter">partition_name1</replaceable>,
- <replaceable class="parameter">partition_name2</replaceable>, [...]
- can be arbitrary.
+ The partition bound specifications for merged partitions can be arbitrary.
</para>
</listitem>
</itemizedlist>
- The new partition <replaceable class="parameter">partition_name</replaceable>
- can have the same name as one of the merged partitions. Only simple,
- non-partitioned partitions can be merged.
</para>
<para>
- If merged partitions have different owners, an error will be generated.
- The owner of the merged partitions will be the owner of the new partition.
- It is the user's responsibility to setup <acronym>ACL</acronym> on the
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
new partition.
</para>
+
<para>
- The indexes and identity are created later, after moving the data
- into the new partition.
- Extended statistics aren't copied from the parent table, for consistency with
- <command>CREATE TABLE PARTITION OF</command>.
- The new partition will inherit the same table access method, persistence
- type, and tablespace as the parent table.
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned table itself
+ as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partition. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
</para>
+
<para>
- When partitions are merged, any individual objects belonging to those
- partitions, such as constraints or statistics, will be dropped. This occurs
- because <command>ALTER TABLE MERGE PARTITIONS</command> uses the partitioned table itself as the
- template to define these objects.
- </para>
- <para>
- If merged partitions have some objects dependent on them, the command can
- not be done (<literal>CASCADE</literal> is not used, and an error will
- be returned).
+ When partitions are merged, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped.
+ Eventually we will drop all the merged partitions (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
</para>
+
<note>
<para>
Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
--
2.34.1
Hi, Jiah He!
1.
please check the attach doc refactor for v62-0001.
Thanks for the changes, they look good (in translation).
2.
here ereport should be elog(ERROR...).
since this error should be unreachable. see check_nested_generated,
cookDefault.
Changed.
3.
"(as for LIKE and inheritances)":
I think you meant, “CREATE TABLE LIKE and table inheritance reject
whole-row check constraint, here we will do the same”.
maybe change to ""(as for CREATE TABLE LIKE and inheritances)".
Changed.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v63-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v63-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 8fbd2686e09806b5fb165a03fd483fc1ee017356 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v63 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 125 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 885 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3653 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index bea9f90138..f8dc2a1020 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,115 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned table itself
+ as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partition. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped.
+ Eventually we will drop all the merged partitions (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1506,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1950,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 6002fd0002..ef8882cbcd 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5fd8b51312..5eea2a6cb2 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20196,6 +20217,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20397,23 +20449,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22012,3 +22048,818 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index dc0c288667..a845c435ff 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2374,6 +2374,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2388,6 +2389,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2401,6 +2403,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2417,6 +2434,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17988,6 +18006,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18616,6 +18635,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 822cf4ec45..60c1036ce8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index ad37f9f6ed..9f7f8b8dd0 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2761,6 +2761,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3034,6 +3035,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4e445fe0cd..f0cb53b20f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 84182eaaae..aff7df3759 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -338,6 +338,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 083b6e3a88..f6fc10d343 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f9450cdc47..6b8e365ae0 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v63-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v63-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 1bb936155122d261c87bea4f1bb30ab49fa2c9e7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v63 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 115 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 733 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 33 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4574 insertions(+), 38 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index f8dc2a1020..5566e249e2 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1256,6 +1260,91 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have <literal>DEFAULT</literal> partition,
+ <literal>DEFAULT</literal> partition can be defined as one of the new partitions.
+ </para>
+
+ <para>
+ Bounds of new partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bound of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition remains with the same
+ name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partitions. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to reconstruct these objects later.
+ Eventually we will drop the split partition (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE SPLIT PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1263,7 +1352,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1507,7 +1597,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1517,7 +1607,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1950,6 +2041,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5eea2a6cb2..bf83e8318e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22863,3 +22878,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a845c435ff..bd2e502292 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -647,6 +648,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2364,6 +2367,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2408,6 +2428,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18076,6 +18110,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18716,6 +18751,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..d09ce12749 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 60c1036ce8..f1de7ced76 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,691 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that are in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+ bool isnull1 = false;
+ bool isnull2 = false;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ if (val1->constisnull)
+ {
+ if (isnull2)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull1 = true;
+ continue;
+ }
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ isnull2 = true;
+ continue;
+ }
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make Const for getting string representation of not found value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare lower
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 9f7f8b8dd0..e891e30b05 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2761,7 +2761,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3024,10 +3024,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3035,6 +3035,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f0cb53b20f..8435bef286 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,39 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITOINS and ALTER TABLE SPLIT PARTITOINS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2501,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index aff7df3759..0f78f1e961 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -423,6 +423,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index f6fc10d343..8b50edbee6 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..e68baf71da
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6b8e365ae0..4096d2bfa6 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..0e79c036ea
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 5290b91e83..06e82a25c0 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2785,6 +2785,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2851,6 +2852,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
On Mon, Sep 22, 2025 at 11:12 PM Dmitry Koval <d.koval@postgrespro.ru>
wrote:
Hi, Jiah He!
1.
duplicated CommandCounterIncrement call?
Probably this duplication is necessary to rename partition correctly ...
The second CommandCounterIncrement() is needed to make the renamed relation
visible within our transaction. Why do we need the first one? I see tests
pass without it.
Also, I doubt this is correct in the partitions_listdatum_intersection()
function.
foreach_node(Const, val1, list1)
{
if (val1->constisnull)
{
if (isnull2)
{
result = lappend(result, val1);
return result;
}
isnull1 = true;
continue;
}
The branch handling null value in the outer loop, uses null2 flag from the
inner loop. I think for the null value of the outer loop we still need to
run inner loop to search for the matching null value.
------
Regards,
Alexander Korotkov
Supabase
Hi Alexander!
1.
The second CommandCounterIncrement() is needed to make the renamed
relation visible within our transaction. Why do we need the first
one? I see tests pass without it.
It's strange. If I comment the first "CommandCounterIncrement();", in block
-----------------------------------------------------------------------
/*
* We must bump the command counter to make the split partition tuple
* visible for renaming.
*/
CommandCounterIncrement();
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), ...);
RenameRelationInternal(splitRelOid, tmpRelName, true, false);
/*
* We must bump the command counter to make the split partition tuple
* visible after renaming.
*/
CommandCounterIncrement();
-----------------------------------------------------------------------
, I got the error "ERROR: tuple already updated by self" in the
partition_split.sql test (Ubuntu). If I comment the second
"CommandCounterIncrement();", I got the error "ERROR: relation
"sales_others" already exists" in the same test.
2.
The branch handling null value in the outer loop, uses null2 flag from
the inner loop. I think for the null value of the outer loop we still
need to run inner loop to search for the matching null value.
This code looks a little confusing, but it probably works correctly.
This can be verified using two typical examples:
-----------------------------------------------------------------------
list1: (NULL, 1)
list2: (2, NULL)
(1) isnull1 = true, (2) "if (isnull1) lappend(NULL)"
-----------------------------------------------------------------------
list1: (1, NULL)
list2: (NULL, 2)
(1) isnull2 = true, (2) "if (isnull2) lappend(NULL)"
-----------------------------------------------------------------------
In both cases, we return from the function immediately after lappend.
This works because we need to find exactly one repeating value.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Tue, Oct 28, 2025 at 1:12 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
1.
The second CommandCounterIncrement() is needed to make the renamed
relation visible within our transaction. Why do we need the first
one? I see tests pass without it.It's strange. If I comment the first "CommandCounterIncrement();", in block
-----------------------------------------------------------------------
/*
* We must bump the command counter to make the split partition tuple
* visible for renaming.
*/
CommandCounterIncrement();
/* Rename partition. */
sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), ...);
RenameRelationInternal(splitRelOid, tmpRelName, true, false);
/*
* We must bump the command counter to make the split partition tuple
* visible after renaming.
*/
CommandCounterIncrement();
-----------------------------------------------------------------------
, I got the error "ERROR: tuple already updated by self" in the
partition_split.sql test (Ubuntu). If I comment the second
"CommandCounterIncrement();", I got the error "ERROR: relation
"sales_others" already exists" in the same test.
Sorry, actually it fails. It appears that the first
CommandCounterIncrement() is needed to see the result of
detachPartitionTable().
2.
The branch handling null value in the outer loop, uses null2 flag from
the inner loop. I think for the null value of the outer loop we still
need to run inner loop to search for the matching null value.This code looks a little confusing, but it probably works correctly.
This can be verified using two typical examples:
-----------------------------------------------------------------------
list1: (NULL, 1)
list2: (2, NULL)(1) isnull1 = true, (2) "if (isnull1) lappend(NULL)"
-----------------------------------------------------------------------
list1: (1, NULL)
list2: (NULL, 2)(1) isnull2 = true, (2) "if (isnull2) lappend(NULL)"
-----------------------------------------------------------------------
In both cases, we return from the function immediately after lappend.
This works because we need to find exactly one repeating value.
How this function could handle this case?
list1: (NULL)
list2: whatever containing NULL
The outer loop will just quit after iterating the only element of
list1 without even iterating list2.
------
Regards,
Alexander Korotkov
Supabase
Hi Alexander!
How this function could handle this case?
list1: (NULL)
list2: whatever containing NULLThe outer loop will just quit after iterating the only element of
list1 without even iterating list2.
Thanks for the case!
Patches with the fix are attached to email.
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
Attachments:
v64-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchtext/plain; charset=UTF-8; name=v64-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From e0db831d742f0dc98a5b79ab5f6f52cdab9e7a43 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:57:22 +0300
Subject: [PATCH v64 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into the one partition of the
target table. The target partition is created using new
createPartitionTable() function with parent partition as the template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao, Jian He
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 125 +-
src/backend/catalog/dependency.c | 50 +
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 885 ++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 146 +++
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3653 insertions(+), 26 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 65bc070d2e..ddb1376a6e 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4450,6 +4450,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index bea9f90138..f8dc2a1020 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,115 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned table itself
+ as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partition. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped.
+ Eventually we will drop all the merged partitions (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1506,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1950,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 7dded634eb..6bea75bb68 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object,
table_close(depRel, RowExclusiveLock);
}
+/*
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
/*
* performMultipleDeletions: Similar to performDeletion, but act on multiple
* objects at once.
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 9944e4bd2d..63bf0edfc4 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5fd8b51312..5eea2a6cb2 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20196,6 +20217,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /* OK to create inheritance. Rest of the checks performed there */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20397,23 +20449,7 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, 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);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
* Generate partition constraint from the partition bound specification.
@@ -22012,3 +22048,818 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy default, if present and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference tableoid. newRel, parent_rel tableoid clear is not
+ * the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * Partitioned table can not have NO INHERIT check constraint (see
+ * StoreRelCheck function).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expresssion may reference tableoid, so
+ * later in MergePartitionsMoveRows, we need evulate the check constraint
+ * again for the newRel. We can check weather check constraint contain
+ * tableoid reference or not via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add check only if it contains tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints any more. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * cannot have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If existing rel is temp, it must belong to this session */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to temporary parent */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create work queue entry for newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values and generated values */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so fresh relcache entry have
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also vertify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of merged partition to new
+ * partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed in
+ * here, so delete the ALTER TABLE queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store a next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway but catching
+ * this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /* Create table for new partition, use partitioned table as model. */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a4b29c822e..cefddd68d6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2374,6 +2374,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2388,6 +2389,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2401,6 +2403,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2417,6 +2434,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -17997,6 +18015,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18625,6 +18644,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d..564ba55b6d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge
+ * Analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of resulting
+ * 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;
+
+ 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"));
+
+ /* Does partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate bound of resulting 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
@@ -3786,6 +3918,20 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 8ba038c5ef..7cf14d487e 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge().
+ * This function compares upper bound of first_bound and lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * 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
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 of
+ * lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ 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.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ 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, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * Lower bound of first partition is the lower bound of merged
+ * partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * Upper bound of last partition is the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 36ea6a4d55..c0b7763fc6 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2761,6 +2761,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3034,6 +3035,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 0ea7ccf524..f54233499b 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ecbddd12e1..4ecf602e0b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 84182eaaae..aff7df3759 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -338,6 +338,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index cf93f9e5be..25c311ff9b 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..5f6472671b
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 5afae33d37..8541546678 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,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..f3c5ce2fbf
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a34..c403c2f569 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d..31e69100a3 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc..7de5ddb878 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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..3e40abf38a
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index a0f5fab0f5..ae3ae10e2c 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 0000000000..ffb498612a
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.40.1.windows.1
v64-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchtext/plain; charset=UTF-8; name=v64-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 715735c27a1196ff99aaad6a476064e6253cfaef Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 7 Apr 2024 00:58:09 +0300
Subject: [PATCH v64 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several parititions.
Just like ALTER TABLE ... MERGE PARTITIONS ... command, new patitions are
created using createPartitionTable() function with parent partition as the
template.
This commit comprises quite naive implementation which works in single process
and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the
operations including the tuple routing. This is why this new DDL command
can't be recommended for large partitioned tables under a high load. However,
this implementation come in handy in certain cases even as is.
Also, it could be used as a foundation for future implementations with lesser
locking and possibly parallel.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval
Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby
Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He
Fixes (summary information).
Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker
Authors: Fujii Masao
Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov
Reviewed-by: Masahiko Sawada
Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi
Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 115 +-
src/backend/commands/tablecmds.c | 430 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 194 +-
src/backend/partitioning/partbounds.c | 723 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 33 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4564 insertions(+), 38 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index ddb1376a6e..c220a1cbc0 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4471,6 +4471,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index f8dc2a1020..5566e249e2 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1256,6 +1260,91 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition, one of
+ the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have <literal>DEFAULT</literal> partition,
+ <literal>DEFAULT</literal> partition can be defined as one of the new partitions.
+ </para>
+
+ <para>
+ Bounds of new partitions should not overlap with new and existing partitions
+ (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bound of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition remains with the same
+ name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
+ as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions, identity columns,
+ indexes, triggers are copied from the partitioned table to the new
+ partitions. But extended statistics, security policies etc won't copied from
+ the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects depend on this partition, such as
+ constraints, triggers, extended statistics etc will be dropped. This occurs
+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to reconstruct these objects later.
+ Eventually we will drop the split partition (using <literal>RESTRICT</literal> mode) too,
+ therefore if any objects still dependent on it,
+ <command>ALTER TABLE SPLIT PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1263,7 +1352,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1507,7 +1597,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1517,7 +1607,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1950,6 +2041,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5eea2a6cb2..bf83e8318e 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22863,3 +22878,418 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with context of new partition for inserting rows from split partition
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking slot for partition
+ * (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structore with generated column expressions
+ * and check constraint expresssions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create structure for check partition constraint
+ * for new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of split partition to new partition
+ * (for first new partition, but other new partitions can use the same
+ * map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for current slot srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up existing relation by new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * be dropped. However, since the drop behavior is DROP_RESTRICT and the
+ * merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If new partition has the same name as split partition then we should
+ * rename split partition for reusing name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also lock down security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determine namespace in createPartitionTable call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from split partition to new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index cefddd68d6..d24bf81244 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -647,6 +648,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2364,6 +2367,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2408,6 +2428,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18085,6 +18119,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18725,6 +18760,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 564ba55b6d..d09ce12749 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool is_merge)
{
Relation partRel;
@@ -3527,25 +3529,175 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ is_merge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit
+ * Analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock partition, check ownership along the way. We need to use
+ * AccessExclusiveLock here, because this split partition will be detached
+ * then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not DEFAULT and DEFAULT partition
+ * exists, then the resulting split partitions cannot be DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge
* Analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3774,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,7 +4062,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
+ transformPartitionCmd(&cxt, partcmd->bound);
/* assign transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4084,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4528,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4543,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4553,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 7cf14d487e..d30624b163 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,23 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge().
+ * 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 equal.
+ * second_bound. These bounds should be equal except when
+ * "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 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 new partitions is DEFAULT
+ * is_merge: true indicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5010,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5033,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5157,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5197,681 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that are in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ bool isnull1 = val1->constisnull;
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ continue;
+ }
+ else if (isnull1)
+ continue;
+
+ /* Compare two datums values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of new partitions) then lower bound of "spec" should be equal (or
+ * greater than or equal in case defaultPart=true) to lower bound of split
+ * partition. If last=true (this means that "spec" is the last of new
+ * partitions) then upper bound of "spec" should be equal (or less than or
+ * equal in case defaultPart=true) to upper bound of split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true in case new partition "spec" is first of new partitions
+ * last: true in case new partition "spec" is last of new partitions
+ * defaultPart: true in case new partitions contain DEFAULT partition
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First check if the resulting range would be empty with specified lower
+ * and upper bounds. partition_rbound_cmp cannot return zero here, since
+ * the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /* Need to check first and last partitions (from set of new partitions) */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal to the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal to the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that bounds of new partition are inside bounds of split partition
+ * (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of new partition "spec" in existing partitions. All
+ * of them should be in split partition (with Oid splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true in case any of new partitions contains value "value".
+ *
+ * partsupfunc: information about comparison function associated with the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to array with new partitions descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct for determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in PartitionDesc of
+ * partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found value that split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make Const for getting string representation of not found value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In case new partitions or existing partitions contains DEFAULT
+ * partition, new partitions can have any bounds inside split
+ * partition bound (can be spaces between partitions bounds).
+ * 3. In case new partitions not contains DEFAULT partition and
+ * partitioned table does not have DEFAULT partition the following
+ * should be true: sum bounds of new partitions should be equal
+ * to bound of split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts count number of split partitions, but it exclude the default
+ * partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make array new_parts with new partitions except DEFAULT partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* Indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * For simplify check for ranges of new partitions need to sort all
+ * partitions in ascending order of them bounds (we compare lower
+ * bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * In case split partition is DEFAULT partition we can use any
+ * free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that bound of current partition is inside bound of split
+ * partition. For range partitioning: checks that upper bound of
+ * previous partition is equal to lower bound of current
+ * partition. For list partitioning: checks that split partition
+ * contains all values of current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of split partition contains in new
+ * partitions. Skip this check if DEFAULT partition exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index c0b7763fc6..16de3e5057 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2761,7 +2761,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3024,10 +3024,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3035,6 +3035,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4ecf602e0b..a8022b0988 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,39 @@ typedef struct PartitionRangeDatum
ParseLoc 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITOINS and ALTER TABLE SPLIT PARTITOINS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2501,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index aff7df3759..0f78f1e961 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -423,6 +423,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 25c311ff9b..e57c5c2049 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 0000000000..02a5bb4f1f
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 8541546678..8503dd801a 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -111,6 +111,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 0000000000..af954be5dc
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569..13ccfb74f5 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a3..1e75feaa45 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb878..17d72e412f 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 0000000000..e68baf71da
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index ae3ae10e2c..96da8d22ff 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 0000000000..0e79c036ea
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 018b5919cf..1db03bdbf7 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2787,6 +2787,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2853,6 +2854,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.40.1.windows.1
Hi!
On Fri, Oct 31, 2025 at 5:41 PM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Hi Alexander!
How this function could handle this case?
list1: (NULL)
list2: whatever containing NULLThe outer loop will just quit after iterating the only element of
list1 without even iterating list2.Thanks for the case!
Patches with the fix are attached to email.
I went though the patchset and did a lot of cleaning and grammar
corrections for comments and commit messages. During the previous
attempt for this patch, I had to revert it mainly because of the
security issue caused by repeated table lookup by its name. The
present version doesn't have this problem, because it doesn't do the
repeated lookup. Additionally, the patchset went through many series
of detailed review. I dare give this patchset another chance. I'm
going to push this if no objections.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v65-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v65-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From ea2eca5c2d0108d9975a22db7d087b8a001af221 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:08:39 +0200
Subject: [PATCH v65 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into a single partition of the
target table. The target partition is created using the new
createPartitionTable() function with the parent partition as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why this new DDL
command can't be recommended for large partitioned tables under a high load.
However, this implementation comes in handy in certain cases, even as it is.
Also, it could serve as a foundation for future implementations with less
locking and possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 127 +-
src/backend/catalog/dependency.c | 54 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 894 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 152 ++-
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3668 insertions(+), 32 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 09ad8400fd0..7b90789f87c 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4743,6 +4743,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9d23ad5a0fb..5cda1c94adb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,117 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ the new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned
+ table itself as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity
+ columns, indexes, and triggers are copied from the partitioned table to
+ the new partition. But extended statistics, security policies, etc,
+ won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depending on this partition,
+ such as constraints, triggers, extended statistics, etc, will be
+ dropped.
+ Eventually, we will drop all the merged partitions
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on them,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1508,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1952,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 8e70a85a3f7..89eac9139c0 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -321,13 +321,63 @@ performDeletion(const ObjectAddress *object,
}
/*
- * performMultipleDeletions: Similar to performDeletion, but act on multiple
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
+/*
+ * performMultipleDeletions: Similar to performDeletion, but acts on multiple
* objects at once.
*
* The main difference from issuing multiple performDeletion calls is that the
* list of objects that would be implicitly dropped, for each object to be
* dropped, is the union of the implicit-object list for all objects. This
- * makes each check be more relaxed.
+ * makes each check more relaxed.
*/
void
performMultipleDeletions(const ObjectAddresses *objects,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 5b2a8132306..81157edf6b0 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 07e5b95782e..441cae9262a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20231,6 +20252,40 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /*
+ * Create an inheritance; the relevant checks are performed inside the
+ * function.
+ */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20432,26 +20487,10 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, rel, attachrel);
-
- /* and triggers */
- CloneRowTriggersToPartition(rel, attachrel);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
- * Clone foreign key constraints. Callee is responsible for setting up
- * for phase 3 constraint verification.
- */
- CloneForeignKeyConstraints(wqueue, rel, attachrel);
-
- /*
- * Generate partition constraint from the partition bound specification.
+ * Generate a partition constraint from the partition bound specification.
* If the parent itself is a partition, make sure to include its
* constraint as well.
*/
@@ -22047,3 +22086,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of the new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values, and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match, etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy the default, if present, and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference the tableoid. newRel, parent_rel tableoid clear is
+ * not the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * The partitioned table can not have a NO INHERIT check constraint
+ * (see StoreRelCheck function for details).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* Install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible. */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expression may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need to evaluate the check constraint
+ * again for the newRel. We can check whether the check constraint
+ * contains a tableoid reference via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add a check only if it contains a tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints anymore. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * can't have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for the partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * Returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If the existing rel is temp, it must belong to this session. */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate the relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for the new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to a temporary parent. */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have an
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create a work queue entry for the newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values, and generated values. */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so a fresh relcache entry has
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also verify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create the necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of the merged partition to the
+ * new partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed it
+ * here, so delete the ALTER TABLE queue for it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store the next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway, but
+ * catching this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of the merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate a temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need to be dropped. However, since the drop behavior is DROP_RESTRICT
+ * and the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation. */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /*
+ * Create a table for the new partition, using the partitioned table as a
+ * model.
+ */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to the new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3a0a354a9c..31883077890 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2395,6 +2395,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2409,6 +2410,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2422,6 +2424,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2438,6 +2455,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -18038,6 +18056,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18668,6 +18687,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d5..bf02e38785d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge -
+ * analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of the resulting
+ * 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;
+
+ 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"));
+
+ /* Does the partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search the DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached and then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is the current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate the bound of the resulting partition. */
+ Assert(partcmd->bound == NULL);
+ partcmd->bound = makeNode(PartitionBoundSpec);
+
+ /* Fill the 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
@@ -3786,12 +3918,26 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
- * Currently, we shouldn't actually get here for subcommand
- * types that don't require transformation; but if we do, just
- * emit them unchanged.
+ * Currently, we shouldn't actually get here for the
+ * subcommand types that don't require transformation; but if
+ * we do, just emit them unchanged.
*/
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 8ba038c5ef4..d9d138731f8 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge(). This
+ * function compares the upper bound of first_bound and the lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * parent: partitioned table
+ * first_name: name of the first partition
+ * first_bound: bound of the first partition
+ * second_name: name of the second partition
+ * second_bound: bound of the second partition
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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);
+
+ /*
+ * cmpval == false for the correct comparison result of the lower and
+ * upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ ReleaseSysCache(tuple);
+ return boundspec;
+}
+
+/*
+ * calculate_partition_bound_for_merge
+ *
+ * Calculates the bound of the merged partition "spec" by using the bounds of
+ * the 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 to 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 an array of lower bounds and a list of
+ * PartitionBoundSpec.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true);
+ bounds = lappend(bounds, bound);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * The lower bound of the first partition is the lower bound
+ * of the merged partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * The upper bound of the last partition is the upper bound of
+ * the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 20d7a65c614..3176fd92ad3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,6 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3046,6 +3047,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 06a8761e3fe..35cc35a0a71 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ece..e43a1f946a9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 5d4fe27ef96..d4cda29c2a2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -339,6 +339,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index cf93f9e5bef..25c311ff9bd 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 00000000000..5f6472671b9
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 112f05a3677..db42c535ba6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,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 00000000000..f3c5ce2fbf1
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a341..c403c2f569f 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d4..31e69100a30 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc1..7de5ddb8785 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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 00000000000..3e40abf38a0
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cc6d799bcea..633cf20e0a6 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..ffb498612a6
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.39.5 (Apple Git-154)
v65-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v65-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 7f5426ab3d2968663ad03c62e610ec3e20b09ba5 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:03:30 +0200
Subject: [PATCH v65 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several partitions. Just
like the ALTER TABLE ... MERGE PARTITIONS ... command, new partitions are
created using the createPartitionTable() function with the parent partition
as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why the new DDL command
can't be recommended for large, partitioned tables under high load. However,
this implementation comes in handy in certain cases, even as it is. Also, it
could serve as a foundation for future implementations with less locking and
possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 118 +-
src/backend/commands/tablecmds.c | 432 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 197 +-
src/backend/partitioning/partbounds.c | 737 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 34 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4585 insertions(+), 40 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7b90789f87c..cea28c00f8a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4764,6 +4764,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5cda1c94adb..9abd8037f28 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1258,6 +1262,94 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition,
+ one of the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, a <literal>DEFAULT</literal> partition can be defined as one
+ of the new partitions.
+ </para>
+
+ <para>
+ The bounds of new partitions should not overlap with those of new or
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bounds of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition
+ <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition
+ remains with the same name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions,
+ identity columns, indexes, and triggers are copied from the partitioned
+ table to the new partitions. But extended statistics, security
+ policies, etc, won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects that depend on this partition,
+ such as constraints, triggers, extended statistics, etc, will be dropped.
+ This occurs because <command>ALTER TABLE SPLIT PARTITION</command> uses
+ the partitioned table itself as the template to reconstruct these
+ objects later.
+ Eventually, we will drop the split partition
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on it, <command>ALTER TABLE SPLIT PARTITION</command>
+ would fail (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1265,7 +1357,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1509,7 +1602,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1519,7 +1612,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1952,6 +2046,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 441cae9262a..7364e73eae5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22905,3 +22920,420 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore the userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with the context of the new partition for inserting rows from the
+ * split partition.
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking a slot for a
+ * partition (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structure with generated column expressions
+ * and check constraint expressions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create a structure to check the partition
+ * constraint for the new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make a boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into a list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create the necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of the split partition to the new
+ * partition (for the first new partition, but other new partitions can
+ * use the same map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for the current slot, srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use the DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from the old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here, we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as a split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach the split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop the
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * to be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If a new partition has the same name as the split partition, then we
+ * should rename the split partition to reuse its name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like a split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from the split partition to the new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to the partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop the split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 31883077890..7fc8bd5b68b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -648,6 +649,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2385,6 +2388,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2429,6 +2449,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18126,6 +18160,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18768,6 +18803,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index bf02e38785d..0c8efabf002 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool isMerge)
{
Relation partRel;
@@ -3527,25 +3529,176 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit -
+ * analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition, sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign the transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock the partition, check ownership along the way. We need to
+ * use AccessExclusiveLock here because this split partition will be
+ * detached, then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not the DEFAULT partition, but the
+ * DEFAULT partition exists, then none of the resulting split partitions
+ * can be the DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge -
* analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3775,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,8 +4063,8 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
- /* assign transformed value of the partition bound */
+ transformPartitionCmd(&cxt, partcmd->bound);
+ /* assign the transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4085,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4529,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4544,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4554,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index d9d138731f8..e940399d6a3 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,22 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge(). This
- * function compares the upper bound of first_bound and the lower bound of
- * second_bound. These bounds should be equal.
+ * This is a helper function for check_partitions_for_split() and
+ * calculate_partition_bound_for_merge(). This function compares the upper
+ * bound of first_bound and the lower bound of second_bound. These bounds
+ * should be equal except when "defaultPart == true" (this means that one of
+ * the split partitions is DEFAULT). In this case, the upper bound of
+ * first_bound can be less than the lower bound of second_bound because
+ * the space between these bounds will be included in the DEFAULT partition.
*
* parent: partitioned table
* first_name: name of the first partition
* first_bound: bound of the first partition
* second_name: name of the second partition
* second_bound: bound of the second partition
+ * defaultPart: true if one of the new partitions is DEFAULT
+ * is_merge: true ndicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5009,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5032,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5156,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5196,694 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that is present in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ bool isnull1 = val1->constisnull;
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ continue;
+ }
+ else if (isnull1)
+ continue;
+
+ /* Compare two datum values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of the new partitions), then the lower bound of "spec" should be
+ * equal (or greater than or equal in case defaultPart=true) to the lower
+ * bound of the split partition. If last=true (this means that "spec" is the
+ * last of the new partitions), then the upper bound of "spec" should be
+ * equal (or less than or equal in case defaultPart=true) to the upper bound
+ * of the split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true iff the new partition "spec" is the first of the
+ * new partitions
+ * last: true iff the new partition "spec" is the last of the
+ * new partitions
+ * defaultPart: true iff new partitions contain the DEFAULT partition
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First, check if the resulting range would be empty with the specified
+ * lower and upper bounds. partition_rbound_cmp cannot return zero here,
+ * since the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to the problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /*
+ * Need to check first and last partitions (from the set of new
+ * partitions)
+ */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that the bounds of the new partition are inside the bounds of the
+ * split partition (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of the new partition "spec" in the existing
+ * partitions. All of them should be in the split partition (with Oid
+ * splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true iff any of the new partitions contains the value
+ * "value".
+ *
+ * partsupfunc: information about the comparison function associated with
+ * the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search for a NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in the PartitionDesc
+ * of partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found the value that the split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make a Const for getting the string representation of the missing
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for the SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In the case when new or existing partitions contain the DEFAULT
+ * partition, new partitions can have any bounds inside the split partition
+ * bound (can be spaces between partition bounds).
+ * 3. In case new partitions don't contain the DEFAULT partition and the
+ * partitioned table does not have the DEFAULT partition, the following
+ * should be true: the sum of the bounds of new partitions should be equal
+ & to the bound of the split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts counts the number of split partitions, but it exclude the
+ * default partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make an array new_parts with new partitions except the DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* An indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * To simplify the check for ranges of new partitions, we need to sort
+ * all partitions in ascending order of their bounds (we compare the
+ * lower bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create an array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder the array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * When the split partition is the DEFAULT partition, we can use
+ * any free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that the bounds of the current partition are inside the
+ * bounds of the split partition. For range partitioning: checks
+ * that the upper bound of the previous partition is equal to the
+ * lower bound of the current partition. For list partitioning:
+ * checks that the split partition contains all values of the
+ * current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of the split partition are contained
+ * in the new partitions. Skip this check if the DEFAULT partition
+ * exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3176fd92ad3..b1ff6f6cd94 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,7 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3036,10 +3036,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3047,6 +3047,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e43a1f946a9..bc7adba4a0f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,40 @@ typedef struct PartitionRangeDatum
ParseLoc location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about a single partition for the 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITIONS and ALTER TABLE SPLIT PARTITIONS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2502,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index d4cda29c2a2..9fde58f541c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -424,6 +424,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 25c311ff9bd..e57c5c20496 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..02a5bb4f1f5
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index db42c535ba6..f2e067b1fbc 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..af954be5dc0
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569f..13ccfb74f55 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a30..1e75feaa453 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb8785..17d72e412ff 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..e68baf71daf
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 633cf20e0a6..89bde9a2850 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..0e79c036ea9
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index c1ad80a418d..583d4dc02ac 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2798,6 +2798,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2865,6 +2866,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.5 (Apple Git-154)
Hi, Alexander!
Thank you for your corrections!
Two questions:
----
1) "v65-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch"
patch, "src/backend/partitioning/partbounds.c" file,
"check_two_partitions_bounds_range" function.
Old comment (v64)
+ /*
+ * lower1=false (the second to last argument) for correct comparison of
+ * lower and upper bounds.
+ */
was changed to (v65)
+ /*
+ * cmpval == false for the correct comparison result of the lower and
+ * upper bounds.
+ */
Maybe it's better to keep the old comment (or keep its meaning)?
----
2) "v65-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch"
patch, "src/backend/parser/parse_utilcmd.c" file, "checkPartition" function.
The third argument of function was changed from "is_merge" (v64) to
"isMerge" (v65). Maybe the function description should be changed in
the same way?
+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE
PARTITIONS";
--
With best regards,
Dmitry Koval
Postgres Professional: http://postgrespro.com
On Wed, Dec 10, 2025 at 1:22 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thank you for your corrections!
Two questions:
----1) "v65-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch"
patch, "src/backend/partitioning/partbounds.c" file,
"check_two_partitions_bounds_range" function.Old comment (v64)
+ /* + * lower1=false (the second to last argument) for correct comparison of + * lower and upper bounds. + */was changed to (v65)
+ /* + * cmpval == false for the correct comparison result of the lower and + * upper bounds. + */Maybe it's better to keep the old comment (or keep its meaning)?
----2) "v65-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch"
patch, "src/backend/parser/parse_utilcmd.c" file, "checkPartition" function.The third argument of function was changed from "is_merge" (v64) to
"isMerge" (v65). Maybe the function description should be changed in
the same way?+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE
PARTITIONS";
Thank you for catching this. Both accepted.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v66-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v66-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From d927e9b683f2d0afa4ef6c96af148e3df44dcfe7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:08:39 +0200
Subject: [PATCH v66 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into a single partition of the
target table. The target partition is created using the new
createPartitionTable() function with the parent partition as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why this new DDL
command can't be recommended for large partitioned tables under a high load.
However, this implementation comes in handy in certain cases, even as it is.
Also, it could serve as a foundation for future implementations with less
locking and possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 127 +-
src/backend/catalog/dependency.c | 54 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 894 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 152 ++-
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3668 insertions(+), 32 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 09ad8400fd0..7b90789f87c 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4743,6 +4743,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9d23ad5a0fb..5cda1c94adb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,117 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ the new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned
+ table itself as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity
+ columns, indexes, and triggers are copied from the partitioned table to
+ the new partition. But extended statistics, security policies, etc,
+ won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depending on this partition,
+ such as constraints, triggers, extended statistics, etc, will be
+ dropped.
+ Eventually, we will drop all the merged partitions
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on them,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1508,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1952,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 8e70a85a3f7..89eac9139c0 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -321,13 +321,63 @@ performDeletion(const ObjectAddress *object,
}
/*
- * performMultipleDeletions: Similar to performDeletion, but act on multiple
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
+/*
+ * performMultipleDeletions: Similar to performDeletion, but acts on multiple
* objects at once.
*
* The main difference from issuing multiple performDeletion calls is that the
* list of objects that would be implicitly dropped, for each object to be
* dropped, is the union of the implicit-object list for all objects. This
- * makes each check be more relaxed.
+ * makes each check more relaxed.
*/
void
performMultipleDeletions(const ObjectAddresses *objects,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 5b2a8132306..81157edf6b0 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 07e5b95782e..441cae9262a 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20231,6 +20252,40 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /*
+ * Create an inheritance; the relevant checks are performed inside the
+ * function.
+ */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20432,26 +20487,10 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, rel, attachrel);
-
- /* and triggers */
- CloneRowTriggersToPartition(rel, attachrel);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
- * Clone foreign key constraints. Callee is responsible for setting up
- * for phase 3 constraint verification.
- */
- CloneForeignKeyConstraints(wqueue, rel, attachrel);
-
- /*
- * Generate partition constraint from the partition bound specification.
+ * Generate a partition constraint from the partition bound specification.
* If the parent itself is a partition, make sure to include its
* constraint as well.
*/
@@ -22047,3 +22086,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of the new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values, and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match, etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy the default, if present, and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference the tableoid. newRel, parent_rel tableoid clear is
+ * not the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * The partitioned table can not have a NO INHERIT check constraint
+ * (see StoreRelCheck function for details).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* Install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible. */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expression may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need to evaluate the check constraint
+ * again for the newRel. We can check whether the check constraint
+ * contains a tableoid reference via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add a check only if it contains a tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints anymore. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * can't have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for the partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * Returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If the existing rel is temp, it must belong to this session. */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate the relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for the new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to a temporary parent. */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have an
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create a work queue entry for the newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values, and generated values. */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so a fresh relcache entry has
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also verify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create the necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of the merged partition to the
+ * new partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed it
+ * here, so delete the ALTER TABLE queue for it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store the next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway, but
+ * catching this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of the merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate a temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need to be dropped. However, since the drop behavior is DROP_RESTRICT
+ * and the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation. */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /*
+ * Create a table for the new partition, using the partitioned table as a
+ * model.
+ */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to the new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3a0a354a9c..31883077890 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2395,6 +2395,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2409,6 +2410,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2422,6 +2424,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2438,6 +2455,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -18038,6 +18056,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18668,6 +18687,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d5..bf02e38785d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge -
+ * analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of the resulting
+ * 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;
+
+ 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"));
+
+ /* Does the partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search the DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached and then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is the current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate the bound of the resulting partition. */
+ Assert(partcmd->bound == NULL);
+ partcmd->bound = makeNode(PartitionBoundSpec);
+
+ /* Fill the 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
@@ -3786,12 +3918,26 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
- * Currently, we shouldn't actually get here for subcommand
- * types that don't require transformation; but if we do, just
- * emit them unchanged.
+ * Currently, we shouldn't actually get here for the
+ * subcommand types that don't require transformation; but if
+ * we do, just emit them unchanged.
*/
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 8ba038c5ef4..236610aae06 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4978,3 +4978,199 @@ 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 calculate_partition_bound_for_merge(). This
+ * function compares the upper bound of first_bound and the lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * parent: partitioned table
+ * first_name: name of the first partition
+ * first_bound: bound of the first partition
+ * second_name: name of the second partition
+ * second_bound: bound of the second partition
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 argument of partition_rbound_cmp() is set to false for the
+ * correct comparison result of the lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ ReleaseSysCache(tuple);
+ return boundspec;
+}
+
+/*
+ * calculate_partition_bound_for_merge
+ *
+ * Calculates the bound of the merged partition "spec" by using the bounds of
+ * the 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 to 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 an array of lower bounds and a list of
+ * PartitionBoundSpec.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true);
+ bounds = lappend(bounds, bound);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * The lower bound of the first partition is the lower bound
+ * of the merged partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * The upper bound of the last partition is the upper bound of
+ * the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 20d7a65c614..3176fd92ad3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,6 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3046,6 +3047,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 06a8761e3fe..35cc35a0a71 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ece..e43a1f946a9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 5d4fe27ef96..d4cda29c2a2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -339,6 +339,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index cf93f9e5bef..25c311ff9bd 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 00000000000..5f6472671b9
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 112f05a3677..db42c535ba6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,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 00000000000..f3c5ce2fbf1
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 50d0354a341..c403c2f569f 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -56,6 +56,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 9ad1cf908d4..31e69100a30 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -35,6 +35,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc1..7de5ddb8785 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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 00000000000..3e40abf38a0
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cc6d799bcea..633cf20e0a6 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..ffb498612a6
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.39.5 (Apple Git-154)
v66-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v66-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From 35fcb2ae0ff54103865e474c94afb91b2e0addf7 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:03:30 +0200
Subject: [PATCH v66 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several partitions. Just
like the ALTER TABLE ... MERGE PARTITIONS ... command, new partitions are
created using the createPartitionTable() function with the parent partition
as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why the new DDL command
can't be recommended for large, partitioned tables under high load. However,
this implementation comes in handy in certain cases, even as it is. Also, it
could serve as a foundation for future implementations with less locking and
possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 118 +-
src/backend/commands/tablecmds.c | 432 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 197 +-
src/backend/partitioning/partbounds.c | 737 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 34 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4585 insertions(+), 40 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7b90789f87c..cea28c00f8a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4764,6 +4764,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5cda1c94adb..9abd8037f28 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1258,6 +1262,94 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition,
+ one of the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, a <literal>DEFAULT</literal> partition can be defined as one
+ of the new partitions.
+ </para>
+
+ <para>
+ The bounds of new partitions should not overlap with those of new or
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bounds of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition
+ <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition
+ remains with the same name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions,
+ identity columns, indexes, and triggers are copied from the partitioned
+ table to the new partitions. But extended statistics, security
+ policies, etc, won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects that depend on this partition,
+ such as constraints, triggers, extended statistics, etc, will be dropped.
+ This occurs because <command>ALTER TABLE SPLIT PARTITION</command> uses
+ the partitioned table itself as the template to reconstruct these
+ objects later.
+ Eventually, we will drop the split partition
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on it, <command>ALTER TABLE SPLIT PARTITION</command>
+ would fail (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1265,7 +1357,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1509,7 +1602,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1519,7 +1612,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1952,6 +2046,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 441cae9262a..7364e73eae5 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22905,3 +22920,420 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore the userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with the context of the new partition for inserting rows from the
+ * split partition.
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking a slot for a
+ * partition (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structure with generated column expressions
+ * and check constraint expressions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create a structure to check the partition
+ * constraint for the new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make a boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into a list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create the necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of the split partition to the new
+ * partition (for the first new partition, but other new partitions can
+ * use the same map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for the current slot, srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use the DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from the old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here, we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as a split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach the split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop the
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * to be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If a new partition has the same name as the split partition, then we
+ * should rename the split partition to reuse its name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like a split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from the split partition to the new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to the partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop the split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 31883077890..7fc8bd5b68b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -648,6 +649,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2385,6 +2388,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2429,6 +2449,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18126,6 +18160,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18768,6 +18803,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index bf02e38785d..375b40b29af 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * isMerge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool isMerge)
{
Relation partRel;
@@ -3527,25 +3529,176 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit -
+ * analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition, sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign the transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock the partition, check ownership along the way. We need to
+ * use AccessExclusiveLock here because this split partition will be
+ * detached, then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not the DEFAULT partition, but the
+ * DEFAULT partition exists, then none of the resulting split partitions
+ * can be the DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge -
* analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3775,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,8 +4063,8 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
- /* assign transformed value of the partition bound */
+ transformPartitionCmd(&cxt, partcmd->bound);
+ /* assign the transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4085,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4529,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4544,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4554,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 236610aae06..4a41b78c7d1 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4984,15 +4985,22 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge(). This
- * function compares the upper bound of first_bound and the lower bound of
- * second_bound. These bounds should be equal.
+ * This is a helper function for check_partitions_for_split() and
+ * calculate_partition_bound_for_merge(). This function compares the upper
+ * bound of first_bound and the lower bound of second_bound. These bounds
+ * should be equal except when "defaultPart == true" (this means that one of
+ * the split partitions is DEFAULT). In this case, the upper bound of
+ * first_bound can be less than the lower bound of second_bound because
+ * the space between these bounds will be included in the DEFAULT partition.
*
* parent: partitioned table
* first_name: name of the first partition
* first_bound: bound of the first partition
* second_name: name of the second partition
* second_bound: bound of the second partition
+ * defaultPart: true if one of the new partitions is DEFAULT
+ * is_merge: true ndicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -5001,6 +5009,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5022,18 +5032,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5136,6 +5156,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5174,3 +5196,694 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that is present in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ bool isnull1 = val1->constisnull;
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ continue;
+ }
+ else if (isnull1)
+ continue;
+
+ /* Compare two datum values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of the new partitions), then the lower bound of "spec" should be
+ * equal (or greater than or equal in case defaultPart=true) to the lower
+ * bound of the split partition. If last=true (this means that "spec" is the
+ * last of the new partitions), then the upper bound of "spec" should be
+ * equal (or less than or equal in case defaultPart=true) to the upper bound
+ * of the split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true iff the new partition "spec" is the first of the
+ * new partitions
+ * last: true iff the new partition "spec" is the last of the
+ * new partitions
+ * defaultPart: true iff new partitions contain the DEFAULT partition
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First, check if the resulting range would be empty with the specified
+ * lower and upper bounds. partition_rbound_cmp cannot return zero here,
+ * since the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to the problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /*
+ * Need to check first and last partitions (from the set of new
+ * partitions)
+ */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that the bounds of the new partition are inside the bounds of the
+ * split partition (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of the new partition "spec" in the existing
+ * partitions. All of them should be in the split partition (with Oid
+ * splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true iff any of the new partitions contains the value
+ * "value".
+ *
+ * partsupfunc: information about the comparison function associated with
+ * the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search for a NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in the PartitionDesc
+ * of partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found the value that the split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make a Const for getting the string representation of the missing
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for the SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In the case when new or existing partitions contain the DEFAULT
+ * partition, new partitions can have any bounds inside the split partition
+ * bound (can be spaces between partition bounds).
+ * 3. In case new partitions don't contain the DEFAULT partition and the
+ * partitioned table does not have the DEFAULT partition, the following
+ * should be true: the sum of the bounds of new partitions should be equal
+ & to the bound of the split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts counts the number of split partitions, but it exclude the
+ * default partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make an array new_parts with new partitions except the DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* An indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * To simplify the check for ranges of new partitions, we need to sort
+ * all partitions in ascending order of their bounds (we compare the
+ * lower bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create an array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder the array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * When the split partition is the DEFAULT partition, we can use
+ * any free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that the bounds of the current partition are inside the
+ * bounds of the split partition. For range partitioning: checks
+ * that the upper bound of the previous partition is equal to the
+ * lower bound of the current partition. For list partitioning:
+ * checks that the split partition contains all values of the
+ * current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of the split partition are contained
+ * in the new partitions. Skip this check if the DEFAULT partition
+ * exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3176fd92ad3..b1ff6f6cd94 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,7 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3036,10 +3036,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3047,6 +3047,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e43a1f946a9..bc7adba4a0f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,40 @@ typedef struct PartitionRangeDatum
ParseLoc location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about a single partition for the 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITIONS and ALTER TABLE SPLIT PARTITIONS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2502,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index d4cda29c2a2..9fde58f541c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -424,6 +424,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 25c311ff9bd..e57c5c20496 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..02a5bb4f1f5
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index db42c535ba6..f2e067b1fbc 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..af954be5dc0
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index c403c2f569f..13ccfb74f55 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 31e69100a30..1e75feaa453 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -38,6 +38,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 7de5ddb8785..17d72e412ff 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..e68baf71daf
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 633cf20e0a6..89bde9a2850 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..0e79c036ea9
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index c1ad80a418d..583d4dc02ac 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2798,6 +2798,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2865,6 +2866,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.5 (Apple Git-154)
Hi,
Patches don't apply anymore.
Could you rebase it please ?
Thank you so much to all of you for your persistence.
Stéphane.
Back.
Le mer. 10 déc. 2025 à 00:54, Alexander Korotkov
<aekorotkov@gmail.com> a écrit :
Show quoted text
On Wed, Dec 10, 2025 at 1:22 AM Dmitry Koval <d.koval@postgrespro.ru> wrote:
Thank you for your corrections!
Two questions:
----1) "v65-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patch"
patch, "src/backend/partitioning/partbounds.c" file,
"check_two_partitions_bounds_range" function.Old comment (v64)
+ /* + * lower1=false (the second to last argument) for correct comparison of + * lower and upper bounds. + */was changed to (v65)
+ /* + * cmpval == false for the correct comparison result of the lower and + * upper bounds. + */Maybe it's better to keep the old comment (or keep its meaning)?
----2) "v65-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patch"
patch, "src/backend/parser/parse_utilcmd.c" file, "checkPartition" function.The third argument of function was changed from "is_merge" (v64) to
"isMerge" (v65). Maybe the function description should be changed in
the same way?+ * is_merge: true indicates the operation is "ALTER TABLE ... MERGE
PARTITIONS";Thank you for catching this. Both accepted.
------
Regards,
Alexander Korotkov
Supabase
On Wed, Dec 10, 2025 at 10:04 PM Stéphane Tachoires
<stephane.tachoires@gmail.com> wrote:
Patches don't apply anymore.
Could you rebase it please ?Thank you so much to all of you for your persistence.
Thank you for pointing this.
Rebased.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v67-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v67-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From 835a5d0ba4221ce55b1d0e26e26756f8443d2a10 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:08:39 +0200
Subject: [PATCH v67 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into a single partition of the
target table. The target partition is created using the new
createPartitionTable() function with the parent partition as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why this new DDL
command can't be recommended for large partitioned tables under a high load.
However, this implementation comes in handy in certain cases, even as it is.
Also, it could serve as a foundation for future implementations with less
locking and possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 127 +-
src/backend/catalog/dependency.c | 54 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 894 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 152 ++-
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 24 +
.../test_ddl_deparse/sql/alter_table.sql | 19 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3703 insertions(+), 32 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 09ad8400fd0..7b90789f87c 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4743,6 +4743,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9d23ad5a0fb..5cda1c94adb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,117 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ the new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned
+ table itself as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity
+ columns, indexes, and triggers are copied from the partitioned table to
+ the new partition. But extended statistics, security policies, etc,
+ won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depending on this partition,
+ such as constraints, triggers, extended statistics, etc, will be
+ dropped.
+ Eventually, we will drop all the merged partitions
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on them,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1508,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1952,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 838ed26d6b9..7489bbd5fb3 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -321,13 +321,63 @@ performDeletion(const ObjectAddress *object,
}
/*
- * performMultipleDeletions: Similar to performDeletion, but act on multiple
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
+/*
+ * performMultipleDeletions: Similar to performDeletion, but acts on multiple
* objects at once.
*
* The main difference from issuing multiple performDeletion calls is that the
* list of objects that would be implicitly dropped, for each object to be
* dropped, is the union of the implicit-object list for all objects. This
- * makes each check be more relaxed.
+ * makes each check more relaxed.
*/
void
performMultipleDeletions(const ObjectAddresses *objects,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 43b4507d86e..672b188930f 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1c9ef53be20..f703293dbc3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20231,6 +20252,40 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /*
+ * Create an inheritance; the relevant checks are performed inside the
+ * function.
+ */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20432,26 +20487,10 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, rel, attachrel);
-
- /* and triggers */
- CloneRowTriggersToPartition(rel, attachrel);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
- * Clone foreign key constraints. Callee is responsible for setting up
- * for phase 3 constraint verification.
- */
- CloneForeignKeyConstraints(wqueue, rel, attachrel);
-
- /*
- * Generate partition constraint from the partition bound specification.
+ * Generate a partition constraint from the partition bound specification.
* If the parent itself is a partition, make sure to include its
* constraint as well.
*/
@@ -22047,3 +22086,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of the new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values, and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match, etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy the default, if present, and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference the tableoid. newRel, parent_rel tableoid clear is
+ * not the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * The partitioned table can not have a NO INHERIT check constraint
+ * (see StoreRelCheck function for details).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* Install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible. */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expression may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need to evaluate the check constraint
+ * again for the newRel. We can check whether the check constraint
+ * contains a tableoid reference via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add a check only if it contains a tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints anymore. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * can't have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for the partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * Returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If the existing rel is temp, it must belong to this session. */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate the relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for the new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to a temporary parent. */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have an
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create a work queue entry for the newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values, and generated values. */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so a fresh relcache entry has
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also verify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create the necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of the merged partition to the
+ * new partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed it
+ * here, so delete the ALTER TABLE queue for it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store the next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway, but
+ * catching this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of the merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate a temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need to be dropped. However, since the drop behavior is DROP_RESTRICT
+ * and the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation. */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /*
+ * Create a table for the new partition, using the partitioned table as a
+ * model.
+ */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to the new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7856ce9d78f..562f11d6677 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2395,6 +2395,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2409,6 +2410,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2422,6 +2424,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2438,6 +2455,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -18038,6 +18056,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18668,6 +18687,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d5..bf02e38785d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge -
+ * analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of the resulting
+ * 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;
+
+ 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"));
+
+ /* Does the partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search the DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached and then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is the current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate the bound of the resulting partition. */
+ Assert(partcmd->bound == NULL);
+ partcmd->bound = makeNode(PartitionBoundSpec);
+
+ /* Fill the 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
@@ -3786,12 +3918,26 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
- * Currently, we shouldn't actually get here for subcommand
- * types that don't require transformation; but if we do, just
- * emit them unchanged.
+ * Currently, we shouldn't actually get here for the
+ * subcommand types that don't require transformation; but if
+ * we do, just emit them unchanged.
*/
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 40ac700d529..b82b29de8f7 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4968,3 +4968,199 @@ 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 calculate_partition_bound_for_merge(). This
+ * function compares the upper bound of first_bound and the lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * parent: partitioned table
+ * first_name: name of the first partition
+ * first_bound: bound of the first partition
+ * second_name: name of the second partition
+ * second_bound: bound of the second partition
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 argument of partition_rbound_cmp() is set to false for the
+ * correct comparison result of the lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ ReleaseSysCache(tuple);
+ return boundspec;
+}
+
+/*
+ * calculate_partition_bound_for_merge
+ *
+ * Calculates the bound of the merged partition "spec" by using the bounds of
+ * the 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 to 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 an array of lower bounds and a list of
+ * PartitionBoundSpec.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true);
+ bounds = lappend(bounds, bound);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * The lower bound of the first partition is the lower bound
+ * of the merged partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * The upper bound of the last partition is the upper bound of
+ * the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 20d7a65c614..3176fd92ad3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,6 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3046,6 +3047,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 06a8761e3fe..35cc35a0a71 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ece..e43a1f946a9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 5d4fe27ef96..d4cda29c2a2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -339,6 +339,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index cf93f9e5bef..25c311ff9bd 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 00000000000..5f6472671b9
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 112f05a3677..db42c535ba6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,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 00000000000..f3c5ce2fbf1
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index f1c6f05fe17..686ebd3242a 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -41,6 +41,30 @@ ALTER TABLE parent ADD CONSTRAINT a_pos CHECK (a > 0);
NOTICE: merging constraint "a_pos" with inherited definition
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint a_pos on table parent
+CREATE TABLE part (
+ a int
+) PARTITION BY RANGE (a);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+CREATE TABLE part1 PARTITION OF part FOR VALUES FROM (1) to (100);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+CREATE TABLE part2 (a int);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type ATTACH PARTITION desc table part2
+ALTER TABLE part DETACH PARTITION part2;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type DETACH PARTITION desc table part2
+DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part ADD PRIMARY KEY (a);
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
+NOTICE: subcommand: type ADD INDEX desc index part_pkey
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type SET NOT NULL (and recurse) desc constraint parent_a_not_null on table parent
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 380ba266075..66cb09b4840 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -24,6 +24,25 @@ ALTER TABLE ONLY grandchild ADD CONSTRAINT a_pos CHECK (a > 0);
-- Constraint, with recursion
ALTER TABLE parent ADD CONSTRAINT a_pos CHECK (a > 0);
+<<<<<<< HEAD
+=======
+CREATE TABLE part (
+ a int
+) PARTITION BY RANGE (a);
+
+CREATE TABLE part1 PARTITION OF part FOR VALUES FROM (1) to (100);
+
+CREATE TABLE part2 (a int);
+ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
+ALTER TABLE part DETACH PARTITION part2;
+DROP TABLE part2;
+
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
+ALTER TABLE part ADD PRIMARY KEY (a);
+
+>>>>>>> d927e9b683f (Implement ALTER TABLE ... MERGE PARTITIONS ... command)
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
ALTER TABLE parent ALTER COLUMN a DROP NOT NULL;
ALTER TABLE parent ALTER COLUMN a SET NOT NULL;
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 193669f2bc1..7de5ddb8785 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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 00000000000..3e40abf38a0
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cc6d799bcea..633cf20e0a6 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..ffb498612a6
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.39.5 (Apple Git-154)
v67-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v67-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From cce93cc2bd76ce24449c5264ca843fea5c7be4c3 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Tue, 9 Dec 2025 17:03:30 +0200
Subject: [PATCH v67 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several partitions. Just
like the ALTER TABLE ... MERGE PARTITIONS ... command, new partitions are
created using the createPartitionTable() function with the parent partition
as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why the new DDL command
can't be recommended for large, partitioned tables under high load. However,
this implementation comes in handy in certain cases, even as it is. Also, it
could serve as a foundation for future implementations with less locking and
possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 118 +-
src/backend/commands/tablecmds.c | 432 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 197 +-
src/backend/partitioning/partbounds.c | 737 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 34 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4585 insertions(+), 40 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7b90789f87c..cea28c00f8a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4764,6 +4764,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5cda1c94adb..9abd8037f28 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1258,6 +1262,94 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition,
+ one of the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, a <literal>DEFAULT</literal> partition can be defined as one
+ of the new partitions.
+ </para>
+
+ <para>
+ The bounds of new partitions should not overlap with those of new or
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bounds of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition
+ <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition
+ remains with the same name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions,
+ identity columns, indexes, and triggers are copied from the partitioned
+ table to the new partitions. But extended statistics, security
+ policies, etc, won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects that depend on this partition,
+ such as constraints, triggers, extended statistics, etc, will be dropped.
+ This occurs because <command>ALTER TABLE SPLIT PARTITION</command> uses
+ the partitioned table itself as the template to reconstruct these
+ objects later.
+ Eventually, we will drop the split partition
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on it, <command>ALTER TABLE SPLIT PARTITION</command>
+ would fail (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1265,7 +1357,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1509,7 +1602,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1519,7 +1612,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1952,6 +2046,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f703293dbc3..953fadb9c6b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22905,3 +22920,420 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore the userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with the context of the new partition for inserting rows from the
+ * split partition.
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking a slot for a
+ * partition (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structure with generated column expressions
+ * and check constraint expressions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create a structure to check the partition
+ * constraint for the new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make a boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into a list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create the necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of the split partition to the new
+ * partition (for the first new partition, but other new partitions can
+ * use the same map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for the current slot, srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use the DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from the old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here, we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as a split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach the split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop the
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * to be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If a new partition has the same name as the split partition, then we
+ * should rename the split partition to reuse its name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like a split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from the split partition to the new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to the partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop the split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 562f11d6677..28f4e11e30f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -648,6 +649,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2385,6 +2388,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2429,6 +2449,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18126,6 +18160,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18768,6 +18803,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index bf02e38785d..375b40b29af 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * isMerge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool isMerge)
{
Relation partRel;
@@ -3527,25 +3529,176 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit -
+ * analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition, sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign the transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock the partition, check ownership along the way. We need to
+ * use AccessExclusiveLock here because this split partition will be
+ * detached, then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not the DEFAULT partition, but the
+ * DEFAULT partition exists, then none of the resulting split partitions
+ * can be the DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge -
* analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3775,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,8 +4063,8 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
- /* assign transformed value of the partition bound */
+ transformPartitionCmd(&cxt, partcmd->bound);
+ /* assign the transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4085,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4529,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4544,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4554,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b82b29de8f7..b7f90ae109d 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4974,15 +4975,22 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge(). This
- * function compares the upper bound of first_bound and the lower bound of
- * second_bound. These bounds should be equal.
+ * This is a helper function for check_partitions_for_split() and
+ * calculate_partition_bound_for_merge(). This function compares the upper
+ * bound of first_bound and the lower bound of second_bound. These bounds
+ * should be equal except when "defaultPart == true" (this means that one of
+ * the split partitions is DEFAULT). In this case, the upper bound of
+ * first_bound can be less than the lower bound of second_bound because
+ * the space between these bounds will be included in the DEFAULT partition.
*
* parent: partitioned table
* first_name: name of the first partition
* first_bound: bound of the first partition
* second_name: name of the second partition
* second_bound: bound of the second partition
+ * defaultPart: true if one of the new partitions is DEFAULT
+ * is_merge: true ndicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -4991,6 +4999,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5012,18 +5022,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5126,6 +5146,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5164,3 +5186,694 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that is present in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ bool isnull1 = val1->constisnull;
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ continue;
+ }
+ else if (isnull1)
+ continue;
+
+ /* Compare two datum values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of the new partitions), then the lower bound of "spec" should be
+ * equal (or greater than or equal in case defaultPart=true) to the lower
+ * bound of the split partition. If last=true (this means that "spec" is the
+ * last of the new partitions), then the upper bound of "spec" should be
+ * equal (or less than or equal in case defaultPart=true) to the upper bound
+ * of the split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true iff the new partition "spec" is the first of the
+ * new partitions
+ * last: true iff the new partition "spec" is the last of the
+ * new partitions
+ * defaultPart: true iff new partitions contain the DEFAULT partition
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First, check if the resulting range would be empty with the specified
+ * lower and upper bounds. partition_rbound_cmp cannot return zero here,
+ * since the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to the problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /*
+ * Need to check first and last partitions (from the set of new
+ * partitions)
+ */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that the bounds of the new partition are inside the bounds of the
+ * split partition (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of the new partition "spec" in the existing
+ * partitions. All of them should be in the split partition (with Oid
+ * splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true iff any of the new partitions contains the value
+ * "value".
+ *
+ * partsupfunc: information about the comparison function associated with
+ * the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search for a NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in the PartitionDesc
+ * of partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found the value that the split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make a Const for getting the string representation of the missing
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for the SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In the case when new or existing partitions contain the DEFAULT
+ * partition, new partitions can have any bounds inside the split partition
+ * bound (can be spaces between partition bounds).
+ * 3. In case new partitions don't contain the DEFAULT partition and the
+ * partitioned table does not have the DEFAULT partition, the following
+ * should be true: the sum of the bounds of new partitions should be equal
+ & to the bound of the split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts counts the number of split partitions, but it exclude the
+ * default partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make an array new_parts with new partitions except the DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* An indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * To simplify the check for ranges of new partitions, we need to sort
+ * all partitions in ascending order of their bounds (we compare the
+ * lower bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create an array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder the array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * When the split partition is the DEFAULT partition, we can use
+ * any free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that the bounds of the current partition are inside the
+ * bounds of the split partition. For range partitioning: checks
+ * that the upper bound of the previous partition is equal to the
+ * lower bound of the current partition. For list partitioning:
+ * checks that the split partition contains all values of the
+ * current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of the split partition are contained
+ * in the new partitions. Skip this check if the DEFAULT partition
+ * exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3176fd92ad3..b1ff6f6cd94 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,7 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3036,10 +3036,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3047,6 +3047,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e43a1f946a9..bc7adba4a0f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,40 @@ typedef struct PartitionRangeDatum
ParseLoc location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about a single partition for the 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITIONS and ALTER TABLE SPLIT PARTITIONS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2502,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index d4cda29c2a2..9fde58f541c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -424,6 +424,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 25c311ff9bd..e57c5c20496 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..02a5bb4f1f5
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index db42c535ba6..f2e067b1fbc 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..af954be5dc0
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 686ebd3242a..205c4e106e2 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -61,6 +61,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 66cb09b4840..27282b6434d 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -40,6 +40,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
>>>>>>> d927e9b683f (Implement ALTER TABLE ... MERGE PARTITIONS ... command)
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 7de5ddb8785..17d72e412ff 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..e68baf71daf
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 633cf20e0a6..89bde9a2850 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..0e79c036ea9
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9dd65b10254..161cbec46af 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2800,6 +2800,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2868,6 +2869,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.5 (Apple Git-154)
On Thu, Dec 11, 2025 at 8:56 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Wed, Dec 10, 2025 at 10:04 PM Stéphane Tachoires
<stephane.tachoires@gmail.com> wrote:Patches don't apply anymore.
Could you rebase it please ?Thank you so much to all of you for your persistence.
Thank you for pointing this.
Rebased.
I found that I didn't rebase properly regression tests in
src/test/modules/test_ddl_deparse. The corrected version is attached.
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v68-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchapplication/octet-stream; name=v68-0001-Implement-ALTER-TABLE-.-MERGE-PARTITIONS-.-comma.patchDownload
From ea1560538f4d58878d1d7ada6f8ff3114a6ed798 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 14 Dec 2025 12:01:20 +0200
Subject: [PATCH v68 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ...
command
This new DDL command merges several partitions into a single partition of the
target table. The target partition is created using the new
createPartitionTable() function with the parent partition as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why this new DDL
command can't be recommended for large partitioned tables under a high load.
However, this implementation comes in handy in certain cases, even as it is.
Also, it could serve as a foundation for future implementations with less
locking and possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 127 +-
src/backend/catalog/dependency.c | 54 +-
src/backend/catalog/pg_constraint.c | 2 +-
src/backend/commands/tablecmds.c | 894 +++++++++++++-
src/backend/parser/gram.y | 22 +-
src/backend/parser/parse_utilcmd.c | 152 ++-
src/backend/partitioning/partbounds.c | 196 +++
src/bin/psql/tab-complete.in.c | 10 +
src/include/catalog/dependency.h | 2 +
src/include/nodes/parsenodes.h | 8 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 6 +
.../isolation/expected/partition-merge.out | 243 ++++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-merge.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 3 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_merge.out | 1097 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_merge.sql | 791 ++++++++++++
22 files changed, 3668 insertions(+), 32 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/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 09ad8400fd0..7b90789f87c 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4743,6 +4743,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
+</programlisting>
+ </para>
+
+ <para>
+ There is also an option for merging multiple table partitions into
+ a single partition using the
+ <link linkend="sql-altertable-merge-partitions"><command>ALTER TABLE ... MERGE PARTITIONS</command></link>.
+ This feature simplifies the management of partitioned tables by allowing
+ users to combine partitions that are no longer needed as
+ separate entities. It's important to note that this operation is not
+ supported for hash-partitioned tables and acquires an
+ <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can
+ merge three monthly partitions into one quarter partition:
+<programlisting>
+ALTER TABLE measurement
+ MERGE PARTITIONS (measurement_y2006m01,
+ measurement_y2006m02,
+ measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
</sect3>
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 9d23ad5a0fb..5cda1c94adb 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1157,18 +1159,117 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-merge-partitions">
+ <term><literal>MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable></literal></term>
+
+ <listitem>
+ <para>
+ This form merges several partitions of the target table into a new partition.
+ Hash-partitioned target table is not supported.
+ Only simple, non-partitioned partitions can be merged.
+ The new partition (<replaceable class="parameter">partition_name</replaceable>)
+ can have the same name as one of the merged partitions
+ (<literal><replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable> [, ...]</literal>).
+ </para>
+
+ <para>
+ If the <literal>DEFAULT</literal> partition is not in the
+ list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ For range-partitioned tables, the ranges of merged partitions
+ must be adjacent in order to be merged.
+ The partition bounds of merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ For list-partitioned tables, the partition bounds of
+ merged partitions are combined to form the new partition bound for
+ <replaceable class="parameter">partition_name</replaceable>.
+ </para>
+ </listitem>
+ </itemizedlist>
+ If the <literal>DEFAULT</literal> partition is in the list of merged partitions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ The partition <replaceable class="parameter">partition_name</replaceable>
+ will be the new <literal>DEFAULT</literal> partition of the target table.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ The partition bound specifications for merged partitions can be arbitrary.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ <para>
+ All merged partitions must have the same owner.
+ The owner of merged partitions will be the owner of the new partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on
+ the new partition.
+ </para>
+
+ <para>
+ <command>ALTER TABLE MERGE PARTITION</command> uses the partitioned
+ table itself as the template to construct the new partition.
+ The new partition will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+
+ Constraints, column defaults, column generation expressions, identity
+ columns, indexes, and triggers are copied from the partitioned table to
+ the new partition. But extended statistics, security policies, etc,
+ won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partition.
+ </para>
+
+ <para>
+ When partitions are merged, any objects depending on this partition,
+ such as constraints, triggers, extended statistics, etc, will be
+ dropped.
+ Eventually, we will drop all the merged partitions
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on them,
+ <command>ALTER TABLE MERGE PARTITION</command> would fail.
+ (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Merging partitions acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ locks on the tables being merged and on the default partition (if any).
+ </para>
+ </note>
+ <note>
+ <para>
+ <command>ALTER TABLE MERGE PARTITIONS</command> creates a new partition and
+ moves data from all merging partitions into it, which can take a long time.
+ So it is not recommended to use the command to merge very big partitions
+ with small ones.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
<para>
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
- <literal>ATTACH PARTITION</literal>, and
- <literal>DETACH PARTITION</literal> can be combined into
+ <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
+ and <literal>MERGE PARTITIONS</literal>, can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
- tables, since only one pass over the table need be made.
+ tables, since only one pass over the table needs to be made.
</para>
<para>
@@ -1407,7 +1508,18 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name</replaceable></term>
<listitem>
<para>
- The name of the table to attach as a new partition or to detach from this table.
+ The name of the table to attach as a new partition or to detach from this table,
+ or the name of the new merged partition.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="sql-altertable-parms-partition-name1">
+ <term><replaceable class="parameter">partition_name1</replaceable></term>
+ <term><replaceable class="parameter">partition_name2</replaceable></term>
+ <listitem>
+ <para>
+ The names of the tables being merged into the new partition.
</para>
</listitem>
</varlistentry>
@@ -1840,6 +1952,13 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To merge several partitions into one partition of the target table:
+<programlisting>
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central)
+ INTO sales_all;
+</programlisting></para>
+
</refsect1>
<refsect1>
diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c
index 838ed26d6b9..7489bbd5fb3 100644
--- a/src/backend/catalog/dependency.c
+++ b/src/backend/catalog/dependency.c
@@ -321,13 +321,63 @@ performDeletion(const ObjectAddress *object,
}
/*
- * performMultipleDeletions: Similar to performDeletion, but act on multiple
+ * performDeletionCheck: Check whether a specific object can be safely deleted.
+ * This function does not perform any deletion; instead, it raises an error
+ * if the object cannot be deleted due to existing dependencies.
+ *
+ * It can be useful when you need to delete some objects later. See comments
+ * in performDeletion too.
+ * The behavior must be specified as DROP_RESTRICT.
+ */
+void
+performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags)
+{
+ Relation depRel;
+ ObjectAddresses *targetObjects;
+
+ Assert(behavior == DROP_RESTRICT);
+
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ AcquireDeletionLock(object, 0);
+
+ /*
+ * Construct a list of objects we want to delete later (ie, the given
+ * object plus everything directly or indirectly dependent on it).
+ */
+ targetObjects = new_object_addresses();
+
+ findDependentObjects(object,
+ DEPFLAG_ORIGINAL,
+ flags,
+ NULL, /* empty stack */
+ targetObjects,
+ NULL, /* no pendingObjects */
+ &depRel);
+
+ /*
+ * Check if deletion is allowed.
+ */
+ reportDependentObjects(targetObjects,
+ behavior,
+ flags,
+ object);
+
+ /* And clean up */
+ free_object_addresses(targetObjects);
+
+ table_close(depRel, RowExclusiveLock);
+}
+
+/*
+ * performMultipleDeletions: Similar to performDeletion, but acts on multiple
* objects at once.
*
* The main difference from issuing multiple performDeletion calls is that the
* list of objects that would be implicitly dropped, for each object to be
* dropped, is the union of the implicit-object list for all objects. This
- * makes each check be more relaxed.
+ * makes each check more relaxed.
*/
void
performMultipleDeletions(const ObjectAddresses *objects,
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 43b4507d86e..672b188930f 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh)
false)));
constr->is_enforced = true;
constr->skip_validation = !conForm->convalidated;
- constr->initially_valid = true;
+ constr->initially_valid = conForm->convalidated;
constr->is_no_inherit = conForm->connoinherit;
notnulls = lappend(notnulls, constr);
}
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1c9ef53be20..f703293dbc3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition);
static char GetAttributeCompression(Oid atttypid, const char *compression);
static char GetAttributeStorage(Oid atttypid, const char *storagemode);
+static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds)
cmd_lockmode = ShareUpdateExclusiveLock;
break;
+ case AT_MergePartitions:
+ cmd_lockmode = AccessExclusiveLock;
+ break;
+
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5271,6 +5277,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_PARTITIONED_TABLE);
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -5667,6 +5678,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);
@@ -6707,6 +6726,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:
@@ -20231,6 +20252,40 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel,
}
}
+/*
+ * attachPartitionTable: attach a new partition to the partitioned table
+ *
+ * wqueue: the ALTER TABLE work queue; can be NULL when not running as part
+ * of an ALTER TABLE sequence.
+ * rel: partitioned relation;
+ * attachrel: relation of attached partition;
+ * bound: bounds of attached relation.
+ */
+static void
+attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound)
+{
+ /*
+ * Create an inheritance; the relevant checks are performed inside the
+ * function.
+ */
+ CreateInheritance(attachrel, rel, true);
+
+ /* Update the pg_class entry. */
+ StorePartitionBound(attachrel, rel, bound);
+
+ /* Ensure there exists a correct set of indexes in the partition. */
+ AttachPartitionEnsureIndexes(wqueue, 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);
+}
+
/*
* ALTER TABLE <name> ATTACH PARTITION <partition-name> FOR VALUES
*
@@ -20432,26 +20487,10 @@ 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, true);
-
- /* Update the pg_class entry. */
- StorePartitionBound(attachrel, rel, cmd->bound);
-
- /* Ensure there exists a correct set of indexes in the partition. */
- AttachPartitionEnsureIndexes(wqueue, rel, attachrel);
-
- /* and triggers */
- CloneRowTriggersToPartition(rel, attachrel);
+ attachPartitionTable(wqueue, rel, attachrel, cmd->bound);
/*
- * Clone foreign key constraints. Callee is responsible for setting up
- * for phase 3 constraint verification.
- */
- CloneForeignKeyConstraints(wqueue, rel, attachrel);
-
- /*
- * Generate partition constraint from the partition bound specification.
+ * Generate a partition constraint from the partition bound specification.
* If the parent itself is a partition, make sure to include its
* constraint as well.
*/
@@ -22047,3 +22086,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
return cstorage;
}
+
+/*
+ * buildExpressionExecutionStates: build the needed expression execution states
+ * for new partition (newPartRel) checks and initialize expressions for
+ * generated columns. All expressions should be created in "tab"
+ * (AlteredTableInfo structure).
+ */
+static void
+buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate)
+{
+ /*
+ * Build the needed expression execution states. Here, we expect only NOT
+ * NULL and CHECK constraint.
+ */
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+
+ /*
+ * We already expanded virtual expression in
+ * createTableConstraints.
+ */
+ con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
+ break;
+ case CONSTR_NOTNULL:
+ /* Nothing to do here. */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+
+ /* Expression already planned in createTableConstraints */
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL);
+}
+
+/*
+ * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated
+ * expressions for "tab" (AlteredTableInfo structure) whose inputs come from
+ * the new tuple (insertslot) of the new partition (newPartRel).
+ */
+static void
+evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab,
+ Relation newPartRel,
+ TupleTableSlot *insertslot,
+ ExprContext *econtext)
+{
+ econtext->ecxt_scantuple = insertslot;
+
+ foreach_ptr(NewColumnValue, ex, tab->newvals)
+ {
+ if (!ex->is_generated)
+ continue;
+
+ insertslot->tts_values[ex->attnum - 1]
+ = ExecEvalExpr(ex->exprstate,
+ econtext,
+ &insertslot->tts_isnull[ex->attnum - 1]);
+ }
+
+ foreach_ptr(NewConstraint, con, tab->constraints)
+ {
+ switch (con->contype)
+ {
+ case CONSTR_CHECK:
+ if (!ExecCheck(con->qualstate, econtext))
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row",
+ con->name, RelationGetRelationName(newPartRel)),
+ errtableconstraint(newPartRel, con->name));
+ break;
+ case CONSTR_NOTNULL:
+ case CONSTR_FOREIGN:
+ /* Nothing to do here */
+ break;
+ default:
+ elog(ERROR, "unrecognized constraint type: %d",
+ (int) con->contype);
+ }
+ }
+}
+
+/*
+ * getAttributesList: build a list of columns (ColumnDef) based on parent_rel
+ */
+static List *
+getAttributesList(Relation parent_rel)
+{
+ AttrNumber parent_attno;
+ TupleDesc modelDesc;
+ List *colList = NIL;
+
+ modelDesc = RelationGetDescr(parent_rel);
+
+ for (parent_attno = 1; parent_attno <= modelDesc->natts;
+ parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(modelDesc,
+ parent_attno - 1);
+ ColumnDef *def;
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid,
+ attribute->atttypmod, attribute->attcollation);
+
+ def->is_not_null = attribute->attnotnull;
+
+ /* Copy identity. */
+ def->identity = attribute->attidentity;
+
+ /* Copy attgenerated. */
+ def->generated = attribute->attgenerated;
+
+ def->storage = attribute->attstorage;
+
+ /* Likewise, copy compression. */
+ if (CompressionMethodIsValid(attribute->attcompression))
+ def->compression =
+ pstrdup(GetCompressionMethodName(attribute->attcompression));
+ else
+ def->compression = NULL;
+
+ /* Add to column list. */
+ colList = lappend(colList, def);
+ }
+
+ return colList;
+}
+
+/*
+ * createTableConstraints:
+ * create check constraints, default values, and generated values for newRel
+ * based on parent_rel. tab is pending-work queue for newRel, we may need it in
+ * MergePartitionsMoveRows.
+ */
+static void
+createTableConstraints(List **wqueue, AlteredTableInfo *tab,
+ Relation parent_rel, Relation newRel)
+{
+ TupleDesc tupleDesc;
+ TupleConstr *constr;
+ AttrMap *attmap;
+ AttrNumber parent_attno;
+ int ccnum;
+ List *constraints = NIL;
+ List *cookedConstraints = NIL;
+
+ tupleDesc = RelationGetDescr(parent_rel);
+ constr = tupleDesc->constr;
+
+ if (!constr)
+ return;
+
+ /*
+ * Construct a map from the parent relation's attnos to the child rel's.
+ * This re-checks type match, etc, although it shouldn't be possible to
+ * have a failure since both tables are locked.
+ */
+ attmap = build_attrmap_by_name(RelationGetDescr(newRel),
+ tupleDesc,
+ false);
+
+ /* Cycle for default values. */
+ for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++)
+ {
+ Form_pg_attribute attribute = TupleDescAttr(tupleDesc,
+ parent_attno - 1);
+
+ /* Ignore dropped columns in the parent. */
+ if (attribute->attisdropped)
+ continue;
+
+ /* Copy the default, if present, and it should be copied. */
+ if (attribute->atthasdef)
+ {
+ Node *this_default = NULL;
+ bool found_whole_row;
+ AttrNumber num;
+ Node *def;
+ NewColumnValue *newval;
+
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
+ this_default = build_generation_expression(parent_rel, attribute->attnum);
+ else
+ {
+ this_default = TupleDescGetDefault(tupleDesc, attribute->attnum);
+ if (this_default == NULL)
+ elog(ERROR, "default expression not found for attribute %d of relation \"%s\"",
+ attribute->attnum, RelationGetRelationName(parent_rel));
+ }
+
+ num = attmap->attnums[parent_attno - 1];
+ def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row);
+
+ if (found_whole_row && attribute->attgenerated != '\0')
+ elog(ERROR, "cannot convert whole-row table reference");
+
+ /* Add a pre-cooked default expression. */
+ StoreAttrDefault(newRel, num, def, true);
+
+ /*
+ * Stored generated column expressions in parent_rel might
+ * reference the tableoid. newRel, parent_rel tableoid clear is
+ * not the same. If so, these stored generated columns require
+ * recomputation for newRel within MergePartitionsMoveRows.
+ */
+ if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
+ {
+ newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval->attnum = num;
+ newval->expr = expression_planner((Expr *) def);
+ newval->is_generated = (attribute->attgenerated != '\0');
+ tab->newvals = lappend(tab->newvals, newval);
+ }
+ }
+ }
+
+ /* Cycle for CHECK constraints. */
+ for (ccnum = 0; ccnum < constr->num_check; ccnum++)
+ {
+ char *ccname = constr->check[ccnum].ccname;
+ char *ccbin = constr->check[ccnum].ccbin;
+ bool ccenforced = constr->check[ccnum].ccenforced;
+ bool ccnoinherit = constr->check[ccnum].ccnoinherit;
+ bool ccvalid = constr->check[ccnum].ccvalid;
+ Node *ccbin_node;
+ bool found_whole_row;
+ Constraint *constr;
+
+ /*
+ * The partitioned table can not have a NO INHERIT check constraint
+ * (see StoreRelCheck function for details).
+ */
+ Assert(!ccnoinherit);
+
+ ccbin_node = map_variable_attnos(stringToNode(ccbin),
+ 1, 0,
+ attmap,
+ InvalidOid, &found_whole_row);
+
+ /*
+ * For the moment we have to reject whole-row variables (as for CREATE
+ * TABLE LIKE and inheritances).
+ */
+ if (found_whole_row)
+ elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".",
+ ccname,
+ RelationGetRelationName(parent_rel));
+
+ constr = makeNode(Constraint);
+ constr->contype = CONSTR_CHECK;
+ constr->conname = pstrdup(ccname);
+ constr->deferrable = false;
+ constr->initdeferred = false;
+ constr->is_enforced = ccenforced;
+ constr->skip_validation = !ccvalid;
+ constr->initially_valid = ccvalid;
+ constr->is_no_inherit = ccnoinherit;
+ constr->raw_expr = NULL;
+ constr->cooked_expr = nodeToString(ccbin_node);
+ constr->location = -1;
+ constraints = lappend(constraints, constr);
+ }
+
+ /* Install all CHECK constraints. */
+ cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints,
+ false, true, true, NULL);
+
+ /* Make the additional catalog changes visible. */
+ CommandCounterIncrement();
+
+ /*
+ * parent_rel check constraint expression may reference tableoid, so later
+ * in MergePartitionsMoveRows, we need to evaluate the check constraint
+ * again for the newRel. We can check whether the check constraint
+ * contains a tableoid reference via pull_varattnos.
+ */
+ foreach_ptr(CookedConstraint, ccon, cookedConstraints)
+ {
+ if (!ccon->skip_validation)
+ {
+ Node *qual;
+ Bitmapset *attnums = NULL;
+
+ Assert(ccon->contype == CONSTR_CHECK);
+ qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1);
+ pull_varattnos(qual, 1, &attnums);
+
+ /*
+ * Add a check only if it contains a tableoid
+ * (TableOidAttributeNumber).
+ */
+ if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber,
+ attnums))
+ {
+ NewConstraint *newcon;
+
+ newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon->name = ccon->name;
+ newcon->contype = CONSTR_CHECK;
+ newcon->qual = qual;
+
+ tab->constraints = lappend(tab->constraints, newcon);
+ }
+ }
+ }
+
+ /* Don't need the cookedConstraints anymore. */
+ list_free_deep(cookedConstraints);
+
+ /* Reproduce not-null constraints. */
+ if (constr->has_not_null)
+ {
+ List *nnconstraints;
+
+ /*
+ * The "include_noinh" argument is false because a partitioned table
+ * can't have NO INHERIT constraint.
+ */
+ nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel),
+ false, false);
+
+ Assert(list_length(nnconstraints) > 0);
+
+ /*
+ * We already set pg_attribute.attnotnull in createPartitionTable. No
+ * need call set_attnotnull again.
+ */
+ AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL);
+ }
+}
+
+/*
+ * createPartitionTable:
+ *
+ * Create a new partition (newPartName) for the partitioned table (parent_rel).
+ * ownerId is determined by the partition on which the operation is performed,
+ * so it is passed separately. The new partition will inherit the access method
+ * and persistence type from the parent table.
+ *
+ * Returns the created relation (locked in AccessExclusiveLock mode).
+ */
+static Relation
+createPartitionTable(List **wqueue, RangeVar *newPartName,
+ Relation parent_rel, Oid ownerId)
+{
+ Relation newRel;
+ Oid newRelId;
+ Oid existingRelid;
+ TupleDesc descriptor;
+ List *colList = NIL;
+ Oid relamId;
+ Oid namespaceId;
+ AlteredTableInfo *new_partrel_tab;
+ Form_pg_class parent_relform = parent_rel->rd_rel;
+
+ /* If the existing rel is temp, it must belong to this session. */
+ if (RELATION_IS_OTHER_TEMP(parent_rel))
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create as partition of temporary relation of another session"));
+
+ /* Look up inheritance ancestors and generate the relation schema. */
+ colList = getAttributesList(parent_rel);
+
+ /* Create a tuple descriptor from the relation schema. */
+ descriptor = BuildDescForRelation(colList);
+
+ /* Look up the access method for the new relation. */
+ relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID;
+
+ /* Look up the namespace in which we are supposed to create the relation. */
+ namespaceId =
+ RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid);
+ if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", newPartName->relname));
+
+ /*
+ * We intended to create the partition with the same persistence as the
+ * parent table, but we still need to recheck because that might be
+ * affected by the search_path. If the parent is permanent, so must be
+ * all of its partitions.
+ */
+ if (parent_relform->relpersistence != RELPERSISTENCE_TEMP &&
+ newPartName->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Permanent rels cannot be partitions belonging to a temporary parent. */
+ if (newPartName->relpersistence != RELPERSISTENCE_TEMP &&
+ parent_relform->relpersistence == RELPERSISTENCE_TEMP)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"",
+ RelationGetRelationName(parent_rel)));
+
+ /* Create the relation. */
+ newRelId = heap_create_with_catalog(newPartName->relname,
+ namespaceId,
+ parent_relform->reltablespace,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ ownerId,
+ relamId,
+ descriptor,
+ NIL,
+ RELKIND_RELATION,
+ newPartName->relpersistence,
+ false,
+ false,
+ ONCOMMIT_NOOP,
+ (Datum) 0,
+ true,
+ allowSystemTableMods,
+ true,
+ InvalidOid,
+ NULL);
+
+ /*
+ * We must bump the command counter to make the newly-created relation
+ * tuple visible for opening.
+ */
+ CommandCounterIncrement();
+
+ /*
+ * Open the new partition with no lock, because we already have an
+ * AccessExclusiveLock placed there after creation.
+ */
+ newRel = table_open(newRelId, NoLock);
+
+ /* Find or create a work queue entry for the newly created table. */
+ new_partrel_tab = ATGetQueueEntry(wqueue, newRel);
+
+ /* Create constraints, default values, and generated values. */
+ createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel);
+
+ /*
+ * Need to call CommandCounterIncrement, so a fresh relcache entry has
+ * newly installed constraint info.
+ */
+ CommandCounterIncrement();
+
+ return newRel;
+}
+
+/*
+ * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions)
+ * of the partitioned table and move rows into the new partition
+ * (newPartRel). We also verify check constraints against these rows.
+ */
+static void
+MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel)
+{
+ CommandId mycid;
+ EState *estate;
+ AlteredTableInfo *tab;
+ ListCell *ltab;
+
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot;
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ tab = ATGetQueueEntry(wqueue, newPartRel);
+
+ /* Generate the constraint and default execution states. */
+ estate = CreateExecutorState();
+
+ buildExpressionExecutionStates(tab, newPartRel, estate);
+
+ mycid = GetCurrentCommandId(true);
+
+ /* Prepare a BulkInsertState for table_tuple_insert. */
+ bistate = GetBulkInsertState();
+
+ /* Create the necessary tuple slot. */
+ dstslot = table_slot_create(newPartRel, NULL);
+
+ foreach_oid(merging_oid, mergingPartitions)
+ {
+ ExprContext *econtext;
+ TupleTableSlot *srcslot;
+ TupleConversionMap *tuple_map;
+ TableScanDesc scan;
+ MemoryContext oldCxt;
+ Snapshot snapshot;
+ Relation mergingPartition;
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForMerge
+ * function.
+ */
+ mergingPartition = table_open(merging_oid, NoLock);
+
+ /* Create a source tuple slot for the partition being merged. */
+ srcslot = table_slot_create(mergingPartition, NULL);
+
+ /*
+ * Map computing for moving attributes of the merged partition to the
+ * new partition.
+ */
+ tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition),
+ RelationGetDescr(newPartRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(mergingPartition, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot);
+ }
+ else
+ {
+ slot_getallattrs(srcslot);
+
+ /* 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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the
+ * tableoid column, so fill tts_tableOid with the desired value.
+ * (We must do this each time, because it gets overwritten with
+ * newrel's OID during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(newPartRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from
+ * the new tuple. We assume these columns won't reference each
+ * other, so that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(newPartRel, insertslot, mycid,
+ ti_options, bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+ table_close(mergingPartition, NoLock);
+ }
+
+ FreeExecutorState(estate);
+ ExecDropSingleTupleTableSlot(dstslot);
+ FreeBulkInsertState(bistate);
+
+ table_finish_bulk_insert(newPartRel, ti_options);
+
+ /*
+ * We don't need to process this newPartRel since we already processed it
+ * here, so delete the ALTER TABLE queue for it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ tab = (AlteredTableInfo *) lfirst(ltab);
+ if (tab->relid == RelationGetRelid(newPartRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+}
+
+/*
+ * detachPartitionTable: detach partition "child_rel" from partitioned table
+ * "parent_rel" with default partition identifier "defaultPartOid"
+ */
+static void
+detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid)
+{
+ /* Remove the pg_inherits row first. */
+ RemoveInheritance(child_rel, parent_rel, false);
+
+ /*
+ * Detaching the partition might involve TOAST table access, so ensure we
+ * have a valid snapshot.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /* Do the final part of detaching. */
+ DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid);
+
+ PopActiveSnapshot();
+}
+
+/*
+ * ALTER TABLE <name> MERGE PARTITIONS <partition-list> INTO <partition-name>
+ */
+static void
+ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation newPartRel;
+ List *mergingPartitions = NIL;
+ Oid defaultPartOid;
+ Oid existingRelid;
+ Oid ownerId = InvalidOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ /*
+ * Check ownership of merged partitions - partitions with different owners
+ * cannot be merged. Also, collect the OIDs of these partitions during the
+ * check.
+ */
+ foreach_node(RangeVar, name, cmd->partlist)
+ {
+ Relation mergingPartition;
+
+ /*
+ * We are going to detach and remove this partition. We already took
+ * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here,
+ * NoLock is fine.
+ */
+ mergingPartition = table_openrv_extended(name, NoLock, false);
+ Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false));
+
+ if (OidIsValid(ownerId))
+ {
+ /* Do the partitions being merged have different owners? */
+ if (ownerId != mergingPartition->rd_rel->relowner)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions being merged have different owners"));
+ }
+ else
+ ownerId = mergingPartition->rd_rel->relowner;
+
+ /* Store the next merging partition into the list. */
+ mergingPartitions = lappend_oid(mergingPartitions,
+ RelationGetRelid(mergingPartition));
+
+ table_close(mergingPartition, NoLock);
+ }
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid);
+
+ /*
+ * Check if this name is already taken. This helps us to detect the
+ * situation when one of the merging partitions has the same name as the
+ * new partition. Otherwise, this would fail later on anyway, but
+ * catching this here allows us to emit a nicer error message.
+ */
+ if (OidIsValid(existingRelid))
+ {
+ if (list_member_oid(mergingPartitions, existingRelid))
+ {
+ /*
+ * The new partition has the same name as one of the merging
+ * partitions.
+ */
+ char tmpRelName[NAMEDATALEN];
+
+ /* Generate a temporary name. */
+ sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+
+ /*
+ * Rename the existing partition with a temporary name, leaving it
+ * free for the new partition. We don't need to care about this
+ * in the future because we're going to eventually drop the
+ * existing partition anyway.
+ */
+ RenameRelationInternal(existingRelid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the new partition
+ * tuple visible for rename.
+ */
+ CommandCounterIncrement();
+ }
+ else
+ {
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", cmd->name->relname));
+ }
+ }
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /* Detach all merging partitions. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ Relation child_rel;
+
+ child_rel = table_open(mergingPartitionOid, NoLock);
+
+ detachPartitionTable(rel, child_rel, defaultPartOid);
+
+ table_close(child_rel, NoLock);
+ }
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop all
+ * merging partitions before we actually do so later. After merging rows
+ * into the new partitions via MergePartitionsMoveRows, all old partitions
+ * need to be dropped. However, since the drop behavior is DROP_RESTRICT
+ * and the merge process (MergePartitionsMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ /* Get oid of the later to be dropped relation. */
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+ }
+
+ /*
+ * Create a table for the new partition, using the partitioned table as a
+ * model.
+ */
+ Assert(OidIsValid(ownerId));
+ newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId);
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(ownerId,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from merged partitions to the new partition. */
+ MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel);
+
+ /* Drop the current partitions before attaching the new one. */
+ foreach_oid(mergingPartitionOid, mergingPartitions)
+ {
+ ObjectAddress object;
+
+ object.objectId = mergingPartitionOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+
+ performDeletion(&object, DROP_RESTRICT, 0);
+ }
+
+ list_free(mergingPartitions);
+
+ /*
+ * Attach a new partition to the partitioned table. wqueue = NULL:
+ * verification for each cloned constraint is not needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, cmd->bound);
+
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7856ce9d78f..562f11d6677 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -762,7 +762,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 PATH
+ PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH
PERIOD PLACING PLAN PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
@@ -2395,6 +2395,7 @@ partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = $4;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -2409,6 +2410,7 @@ partition_cmd:
n->subtype = AT_DetachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = $4;
n->def = (Node *) cmd;
@@ -2422,6 +2424,21 @@ partition_cmd:
n->subtype = AT_DetachPartitionFinalize;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
+ /* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
+ | 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;
@@ -2438,6 +2455,7 @@ index_partition_cmd:
n->subtype = AT_AttachPartition;
cmd->name = $3;
cmd->bound = NULL;
+ cmd->partlist = NIL;
cmd->concurrent = false;
n->def = (Node *) cmd;
@@ -18038,6 +18056,7 @@ unreserved_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
@@ -18668,6 +18687,7 @@ bare_label_keyword:
| PARSER
| PARTIAL
| PARTITION
+ | PARTITIONS
| PASSING
| PASSWORD
| PATH
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index e96b38a59d5..bf02e38785d 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -32,6 +32,7 @@
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/namespace.h"
+#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
@@ -58,6 +59,8 @@
#include "parser/parse_type.h"
#include "parser/parse_utilcmd.h"
#include "parser/parser.h"
+#include "partitioning/partbounds.h"
+#include "partitioning/partdesc.h"
#include "rewrite/rewriteManip.h"
#include "utils/acl.h"
#include "utils/builtins.h"
@@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
}
+/*
+ * checkPartition
+ * Check whether partRelOid is a leaf partition of the parent table (rel).
+ */
+static void
+checkPartition(Relation rel, Oid partRelOid)
+{
+ Relation partRel;
+
+ partRel = table_open(partRelOid, NoLock);
+
+ if (partRel->rd_rel->relkind != RELKIND_RELATION)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (!partRel->rd_rel->relispartition)
+ ereport(ERROR,
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
+ ereport(ERROR,
+ errcode(ERRCODE_UNDEFINED_TABLE),
+ errmsg("relation \"%s\" is not a partition of relation \"%s\"",
+ RelationGetRelationName(partRel), RelationGetRelationName(rel)),
+ errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+
+ table_close(partRel, NoLock);
+}
+
+/*
+ * transformPartitionCmdForMerge -
+ * analyze the ALTER TABLE ... MERGE PARTITIONS command
+ *
+ * Does simple checks for merged partitions. Calculates bound of the resulting
+ * 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;
+
+ 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"));
+
+ /* Does the partitioned table (parent) have 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\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+
+ /*
+ * Search the DEFAULT partition in the list. Open and lock partitions
+ * before calculating the boundary for resulting partition, we also
+ * check for ownership along the way. We need to use
+ * AccessExclusiveLock here, because these merged partitions will be
+ * detached and then dropped in ATExecMergePartitions.
+ */
+ partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0,
+ RangeVarCallbackOwnsRelation,
+ NULL);
+ /* Is the current partition a DEFAULT partition? */
+ if (partOid == defaultPartOid)
+ isDefaultPart = true;
+
+ /*
+ * Extended check because the same partition can have different names
+ * (for example, "part_name" and "public.part_name").
+ */
+ foreach(listptr2, partOids)
+ {
+ Oid curOid = lfirst_oid(listptr2);
+
+ if (curOid == partOid)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name->location));
+ }
+
+ checkPartition(parent, partOid);
+
+ partOids = lappend_oid(partOids, partOid);
+ }
+
+ /* Allocate the bound of the resulting partition. */
+ Assert(partcmd->bound == NULL);
+ partcmd->bound = makeNode(PartitionBoundSpec);
+
+ /* Fill the 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
@@ -3786,12 +3918,26 @@ 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 partitions to be merged should include at least two partitions"));
+
+ transformPartitionCmdForMerge(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
- * Currently, we shouldn't actually get here for subcommand
- * types that don't require transformation; but if we do, just
- * emit them unchanged.
+ * Currently, we shouldn't actually get here for the
+ * subcommand types that don't require transformation; but if
+ * we do, just emit them unchanged.
*/
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index 40ac700d529..b82b29de8f7 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -4968,3 +4968,199 @@ 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 calculate_partition_bound_for_merge(). This
+ * function compares the upper bound of first_bound and the lower bound of
+ * second_bound. These bounds should be equal.
+ *
+ * parent: partitioned table
+ * first_name: name of the first partition
+ * first_bound: bound of the first partition
+ * second_name: name of the second partition
+ * second_bound: bound of the second partition
+ * pstate: pointer to ParseState struct for determining error position
+ */
+static void
+check_two_partitions_bounds_range(Relation parent,
+ RangeVar *first_name,
+ PartitionBoundSpec *first_bound,
+ RangeVar *second_name,
+ PartitionBoundSpec *second_bound,
+ 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 argument of partition_rbound_cmp() is set to false for the
+ * correct comparison result of the lower and upper bounds.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ second_lower->datums, second_lower->kind,
+ false, first_upper);
+ if (cmpval)
+ {
+ PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ }
+}
+
+/*
+ * get_partition_bound_spec
+ *
+ * Returns the PartitionBoundSpec for the partition with the given OID partOid.
+ */
+static PartitionBoundSpec *
+get_partition_bound_spec(Oid partOid)
+{
+ 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 %u", partOid);
+
+ datum = SysCacheGetAttr(RELOID, tuple,
+ Anum_pg_class_relpartbound,
+ &isnull);
+ if (isnull)
+ elog(ERROR, "partition bound for relation %u is null",
+ partOid);
+
+ boundspec = stringToNode(TextDatumGetCString(datum));
+
+ if (!IsA(boundspec, PartitionBoundSpec))
+ elog(ERROR, "expected PartitionBoundSpec for relation %u",
+ partOid);
+
+ ReleaseSysCache(tuple);
+ return boundspec;
+}
+
+/*
+ * calculate_partition_bound_for_merge
+ *
+ * Calculates the bound of the merged partition "spec" by using the bounds of
+ * the 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 to 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 an array of lower bounds and a list of
+ * PartitionBoundSpec.
+ */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ i = foreach_current_index(partoid);
+
+ lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true);
+ bounds = lappend(bounds, bound);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, key);
+
+ /* Ranges of partitions should be adjacent. */
+ 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),
+ pstate);
+ }
+
+ /*
+ * The lower bound of the first partition is the lower bound
+ * of the merged partition.
+ */
+ spec->lowerdatums =
+ ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums;
+
+ /*
+ * The upper bound of the last partition is the upper bound of
+ * the 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:
+ {
+ /* Consolidate bounds for all partitions in the list. */
+ foreach_oid(partoid, partOids)
+ {
+ bound = get_partition_bound_spec(partoid);
+ spec->listdatums = list_concat(spec->listdatums, bound->listdatums);
+ }
+ break;
+ }
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ }
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 20d7a65c614..3176fd92ad3 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,6 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
+ "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3046,6 +3047,15 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> MERGE PARTITIONS ( */
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
+ {
+ set_completion_reference(prev4_wd);
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
+ }
+ else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)"))
+ COMPLETE_WITH("INTO");
+
/* ALTER TABLE <name> OF */
else if (Matches("ALTER", "TABLE", MatchAny, "OF"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes);
diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h
index 06a8761e3fe..35cc35a0a71 100644
--- a/src/include/catalog/dependency.h
+++ b/src/include/catalog/dependency.h
@@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object);
extern void performDeletion(const ObjectAddress *object,
DropBehavior behavior, int flags);
+extern void performDeletionCheck(const ObjectAddress *object,
+ DropBehavior behavior, int flags);
extern void performMultipleDeletions(const ObjectAddresses *objects,
DropBehavior behavior, int flags);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ece..e43a1f946a9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum
} PartitionRangeDatum;
/*
- * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands
+ * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for
+ * ALTER TABLE MERGE PARTITIONS commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach */
+ RangeVar *name; /* name of partition to attach/detach/merge */
PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
+ List *partlist; /* list of partitions to be merged, used in
+ * ALTER TABLE MERGE PARTITIONS */
bool concurrent;
} PartitionCmd;
@@ -2476,6 +2479,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 5d4fe27ef96..d4cda29c2a2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -339,6 +339,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("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index cf93f9e5bef..25c311ff9bd 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 00000000000..5f6472671b9
--- /dev/null
+++ b/src/test/isolation/expected/partition-merge.out
@@ -0,0 +1,243 @@
+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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|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; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+-----------
+tpart_00_20 | 1|text01modif
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 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 s2u2: UPDATE tpart SET i = 21 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |15|text15
+tpart_20_30 |21|text01
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 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 s2u3: UPDATE tpart SET i = 11 where i = 1; <waiting ...>
+step s1c: COMMIT;
+step s2u3: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_20 | 5|text05
+tpart_00_20 |11|text01
+tpart_00_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index 112f05a3677..db42c535ba6 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -109,6 +109,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 00000000000..f3c5ce2fbf1
--- /dev/null
+++ b/src/test/isolation/specs/partition-merge.spec
@@ -0,0 +1,62 @@
+# 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 s2u2 { UPDATE tpart SET i = 21 where i = 1; }
+step s2u3 { UPDATE tpart SET i = 11 where i = 1; }
+step s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+
+
+# s2 inserts row into table. s1 starts MERGE PARTITIONS then
+# s2 is trying to update inserted row and waits until s1 finishes
+# 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
+
+# Tuple routing between partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s
+
+# Tuple routing between merging partitions.
+permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index f1c6f05fe17..6b5b40905e7 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -113,6 +113,11 @@ ALTER TABLE part DETACH PARTITION part2;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type DETACH PARTITION desc table part2
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+NOTICE: DDL test: type simple, tag CREATE TABLE
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index 380ba266075..a0549ef8247 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -60,6 +60,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200);
ALTER TABLE part DETACH PARTITION part2;
DROP TABLE part2;
+CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
+ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+
ALTER TABLE part ADD PRIMARY KEY (a);
CREATE TABLE tbl (
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 193669f2bc1..7de5ddb8785 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,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 00000000000..3e40abf38a0
--- /dev/null
+++ b/src/test/regress/expected/partition_merge.out
@@ -0,0 +1,1097 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is 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" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2...
+ ^
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+ERROR: "sales_apr2022" is not a table
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent.
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+ERROR: partition with name "sales_feb2022" is already used
+LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions...
+ ^
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+ERROR: relation "sales_apr_2" already exists
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+ERROR: cannot drop table sales_jan2022 because other objects depend on it
+DETAIL: view jan2022v depends on table sales_jan2022
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP VIEW jan2022v;
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022')
+ sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021')
+ sales_others | p | r | f | DEFAULT
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+------------------------------------------------+----------------+---------+------------------+--------------------------------------------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022')
+ sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+ schemaname | tablename | indexname | tablespace | indexdef
+--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------
+ partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date)
+(1 row)
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+------------------------------------------------+----------------+------------------+--------------+------------
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022
+ partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_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)
+
+RESET enable_seqscan;
+DROP TABLE sales_range;
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+SELECT * FROM sales_others ORDER BY salesperson_id;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 1 | May | 1000 | 01-31-2022
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 10 | Halder | 350 | 01-28-2022
+ 12 | Plato | 350 | 03-19-2022
+ 13 | Gandi | 377 | 01-09-2022
+ 14 | Smith | 510 | 05-04-2022
+(7 rows)
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+--------------------------------------------------
+ sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022')
+ sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date;
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT * FROM salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+SELECT * FROM salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 10 | May
+ 19 | Ivanov
+ 20 | Smirnoff
+ 30 | Ford
+(4 rows)
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+select * from salespeople;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(6 rows)
+
+select * from salespeople01_10;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 1 | Poirot
+(1 row)
+
+select * from salespeople10_40;
+ salesperson_id | salesperson_name
+----------------+------------------
+ 19 | Ivanov
+ 10 | May
+ 20 | Smirnoff
+ 31 | Popov
+ 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople;
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+(4 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all;
+ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- 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"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+---------------+----------------+---------+------------------+------------------------------------------------------
+ sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv')
+ sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid')
+ sales_others | p | r | f | DEFAULT
+(5 rows)
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------------+----------------+---------+------------------+--------------------------------------------------------------------------------------------------------------
+ sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv')
+ sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki')
+ sales_others | p | r | f | DEFAULT
+(3 rows)
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+------------+----------------+------------------+----------------+--------------+------------
+ sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_all | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022
+ sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+---------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+--------------------------------------------------------------------
+ Index Scan using sales_all_sales_state_idx on sales_all sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_2
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(11 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+ERROR: relation "t1p1" is not a partition of relation "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+ERROR: "t3" is not a partition of partitioned table "t2"
+HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+ Table "partitions_merge_schema.tp_1_2"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ i | integer | | not null | | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2))
+Indexes:
+ "tp_1_2_pkey" PRIMARY KEY, btree (i)
+ "tp_1_2_i_idx" btree (i)
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+
+DROP TABLE t;
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+ search_path
+---------------------------------
+ partitions_merge_schema, public
+(1 row)
+
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3)
+ tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4)
+(2 rows)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | p
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SAVEPOINT s;
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ERROR: cannot create a temporary relation as partition of permanent relation "t"
+ROLLBACK;
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+ oid | relpersistence
+-----+----------------
+ t | t
+(1 row)
+
+EXECUTE get_partition_info('{t}');
+ oid | relpersistence | relkind | inhdetachpending | pg_get_expr
+--------+----------------+---------+------------------+----------------------------
+ tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1)
+ tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2)
+(2 rows)
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ROLLBACK;
+DEALLOCATE get_partition_info;
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_2 | regress_tblspace
+(2 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_2 | tp_0_2_pkey | regress_tblspace
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+-----------------------
+ t | partitions_merge_heap
+ tp_0_2 | partitions_merge_heap
+(2 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_0_1
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: must be owner of table tp_1_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-------------------------------
+ partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice
+(1 row)
+
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+-------------------------+--------+-------+-----------------------------
+ partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob
+(1 row)
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ERROR: partitions being merged have different owners
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+ERROR: partition of hash-partitioned table cannot be merged
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+ERROR: list of partitions to be merged should include at least two partitions
+DROP TABLE t;
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | | tp_0_1.i
+ t | text | | | 'default_tp_0_1'::text | main | | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (1)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1
+Not-null constraints:
+ "tp_0_1_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1')
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+ Table "partitions_merge_schema.tp_0_1"
+ Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+-------------
+ i | integer | | not null | | plain | | |
+ t | text | | | 'default_t'::text | extended | pglz | |
+ b | bigint | | not null | | plain | | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+ tableoid | i | t | b | d
+----------+---+----------------+---+------------
+ tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022
+ tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022
+ tp_0_1 | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+ Table "partitions_merge_schema.tp_0_2"
+ Column | Type | Collation | Nullable | Default
+--------+---------+-----------+----------+---------
+ i | integer | | not null |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Indexes:
+ "tp_0_2_pkey" PRIMARY KEY, btree (i)
+Referenced by:
+ TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED
+
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+DETAIL: Key (i)=(2) is not present in table "t".
+DROP TABLE t_fk;
+DROP TABLE t;
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+DETAIL: Failing row contains (0, virtual).
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+ i
+----
+ 5
+ 15
+ 16
+(3 rows)
+
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+ count
+-------
+ 1
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cc6d799bcea..633cf20e0a6 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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 compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
new file mode 100644
index 00000000000..ffb498612a6
--- /dev/null
+++ b/src/test/regress/sql/partition_merge.sql
@@ -0,0 +1,791 @@
+--
+-- PARTITIONS_MERGE
+-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command
+--
+
+CREATE SCHEMA partitions_merge_schema;
+CREATE SCHEMA partitions_merge_schema2;
+SET search_path = partitions_merge_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+-- ERROR: "sales_apr2022" is not a table
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
+-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
+-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022"
+-- (space between sections sales_jan2022 and sales_mar2022)
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022;
+-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021"
+-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021"
+-- (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: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022;
+--ERROR, sales_apr_2 already exists
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2;
+
+CREATE VIEW jan2022v as SELECT * FROM sales_jan2022;
+ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022;
+DROP VIEW jan2022v;
+
+-- NO ERROR: test for custom partitions order, source partitions not in the search_path
+SET search_path = partitions_merge_schema2, public;
+ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS (
+ partitions_merge_schema.sales_feb2022,
+ partitions_merge_schema.sales_mar2022,
+ partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022;
+SET search_path = partitions_merge_schema, public;
+
+PREPARE get_partition_info(regclass[]) AS
+SELECT c.oid::pg_catalog.regclass,
+ c.relpersistence,
+ c.relkind,
+ i.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 = ANY($1)
+ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT',
+ c.oid::regclass::text COLLATE "C";
+
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table, then merge partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass);
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+-- check schema-qualified name of the new partition
+ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2';
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_range;
+
+--
+-- Merge some partitions into DEFAULT partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (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, partitions_merge_schema.sales_others) INTO sales_others;
+
+SELECT * FROM sales_others ORDER BY salesperson_id;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_range}');
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date;
+
+ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022;
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date;
+DROP TABLE sales_date;
+
+--
+-- Test: merge partitions of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20);
+CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30);
+CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_20 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (30, 'Ford');
+
+SELECT * FROM salespeople01_10;
+SELECT * FROM salespeople10_40;
+
+DROP TABLE salespeople;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: merge partitions with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create partitions with some deleted columns:
+CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30));
+CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov');
+INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff');
+INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov');
+
+ALTER TABLE salespeople10_20 DROP COLUMN d1;
+ALTER TABLE salespeople20_30 DROP COLUMN d2;
+ALTER TABLE salespeople30_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20);
+ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30);
+ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40;
+
+select * from salespeople;
+select * from salespeople01_10;
+select * from salespeople10_40;
+
+DROP TABLE salespeople;
+
+--
+-- Test: merge sub-partitions
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all;
+
+SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT;
+
+
+CREATE TABLE sales_external (LIKE sales_list);
+CREATE TABLE sales_external2 (vch VARCHAR(5));
+
+-- ERROR: "sales_external" is not a partition of partitioned table "sales_list"
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all;
+-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list"
+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
+(salesperson_id INT GENERATED ALWAYS AS IDENTITY,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid');
+CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok');
+CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Helsinki', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Helsinki', 1200, '2022-03-11'),
+ ('Halder', 'Oslo', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all;
+
+-- show partitions with conditions:
+EXECUTE get_partition_info('{sales_list}');
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after merging partitions
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_all WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Try to MERGE partitions of another table.
+--
+CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b);
+CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2);
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C');
+CREATE TABLE t3 (i int, t text);
+
+-- ERROR: relation "t1p1" is not a partition of relation "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p;
+-- ERROR: "t3" is not a partition of partitioned table "t2"
+ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p;
+
+DROP TABLE t3;
+DROP TABLE t2;
+DROP TABLE t1;
+
+
+--
+-- Check the partition index name if the partition name is the same as one
+-- of the merged partitions.
+--
+CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i);
+
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+CREATE INDEX tidx ON t(i);
+ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2;
+
+-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'.
+\d+ tp_1_2
+
+DROP TABLE t;
+
+--
+-- Try to MERGE partitions of temporary table.
+--
+BEGIN;
+SHOW search_path;
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP;
+CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3);
+CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4);
+
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3;
+
+-- Partition should be temporary.
+EXECUTE get_partition_info('{t}');
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4;
+ROLLBACK;
+
+--
+-- Try mixing permanent and temporary partitions.
+--
+BEGIN;
+SET search_path = partitions_merge_schema, pg_temp, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+SAVEPOINT s;
+
+SET search_path = pg_temp, partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+ROLLBACK TO SAVEPOINT s;
+SET search_path = partitions_merge_schema, public;
+-- Can't merge persistent partitions into a temporary partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2;
+ROLLBACK;
+
+BEGIN;
+SET search_path = pg_temp, partitions_merge_schema, public;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass;
+EXECUTE get_partition_info('{t}');
+
+SET search_path = partitions_merge_schema, pg_temp, public;
+
+-- Can't merge temporary partitions into a persistent partition
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+ROLLBACK;
+
+DEALLOCATE get_partition_info;
+
+-- Check the new partition inherits parent's tablespace
+SET search_path = partitions_merge_schema, public;
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check the new partition inherits parent's table access method
+SET search_path = partitions_merge_schema, public;
+CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap;
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partitions_merge_heap;
+
+-- Test permission checks. The user needs to own the parent table and all
+-- the merging partitions to do the merge.
+CREATE ROLE regress_partition_merge_alice;
+CREATE ROLE regress_partition_merge_bob;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice;
+GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob;
+
+SET SESSION AUTHORIZATION regress_partition_merge_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table t
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- ERROR: must be owner of table tp_1_2
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+SET SESSION AUTHORIZATION regress_partition_merge_bob;
+-- Ok:
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: we can't merge partitions with different owners
+CREATE TABLE tp_0_1(i int);
+ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice;
+CREATE TABLE tp_1_2(i int);
+ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob;
+
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+
+-- Owner is 'regress_partition_merge_alice':
+\dt tp_0_1
+-- Owner is 'regress_partition_merge_bob':
+\dt tp_1_2
+
+-- ERROR: partitions being merged have different owners
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+DROP TABLE t;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice;
+REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob;
+DROP ROLE regress_partition_merge_alice;
+DROP ROLE regress_partition_merge_bob;
+
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be merged
+ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3;
+
+-- ERROR: list of partitions to be merged should include at least two partitions
+ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3;
+
+DROP TABLE t;
+
+
+-- Test for merged partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+\set HIDE_TOAST_COMPRESSION false
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_0_1
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_0_1',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1);
+COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i';
+
+CREATE TABLE tp_1_2
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_1_2',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-03-03') STORED);
+ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2);
+COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1;
+CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_0_1');
+CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_1_2');
+
+\d+ tp_0_1
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1;
+\d+ tp_0_1
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+\set HIDE_TOAST_COMPRESSION true
+
+
+-- Test MERGE PARTITIONS with not valid foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT VALID FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+-- Test MERGE PARTITIONS with not enforced foreign key constraint
+CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+INSERT INTO t VALUES (0), (1);
+CREATE TABLE t_fk (i INT);
+INSERT INTO t_fk VALUES (1), (2);
+
+ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED;
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be NOT ENFORCED FOREIGN KEY
+\d tp_0_2
+-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey"
+ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED;
+
+DROP TABLE t_fk;
+DROP TABLE t;
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1);
+CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2;
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+-- Test for generated columns (different order of columns in partitioned table
+-- and partitions).
+CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i);
+CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int);
+ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10);
+ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20);
+ALTER TABLE t ADD CHECK (g > 0);
+ALTER TABLE t ADD CHECK (i > 0);
+INSERT INTO t VALUES (5), (15);
+
+ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12;
+
+INSERT INTO t VALUES (16);
+-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check"
+INSERT INTO t VALUES (0);
+-- Should be 3 rows: (5), (15), (16):
+SELECT i FROM t ORDER BY i;
+-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10:
+SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partitions_merge_schema;
+DROP SCHEMA partitions_merge_schema2;
--
2.39.5 (Apple Git-154)
v68-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchapplication/octet-stream; name=v68-0002-Implement-ALTER-TABLE-.-SPLIT-PARTITION-.-comman.patchDownload
From c1452527e0e771ffbacd259c91d08c91971b6762 Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 14 Dec 2025 12:02:11 +0200
Subject: [PATCH v68 2/2] Implement ALTER TABLE ... SPLIT PARTITION ... command
This new DDL command splits a single partition into several partitions. Just
like the ALTER TABLE ... MERGE PARTITIONS ... command, new partitions are
created using the createPartitionTable() function with the parent partition
as the template.
This commit comprises a quite naive implementation which works in a single
process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all
the operations, including the tuple routing. This is why the new DDL command
can't be recommended for large, partitioned tables under high load. However,
this implementation comes in handy in certain cases, even as it is. Also, it
could serve as a foundation for future implementations with less locking and
possibly parallelism.
Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru
Author: Dmitry Koval <d.koval@postgrespro.ru>
Co-authored-by: Alexander Korotkov <aekorotkov@gmail.com>
Co-authored-by: Tender Wang <tndrwang@gmail.com>
Co-authored-by: Richard Guo <guofenglinux@gmail.com>
Co-authored-by: Dagfinn Ilmari Mannsaker <ilmari@ilmari.org>
Co-authored-by: Fujii Masao <masao.fujii@gmail.com>
Co-authored-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Laurenz Albe <laurenz.albe@cybertec.at>
Reviewed-by: Zhihong Yu <zyu@yugabyte.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Robert Haas <rhaas@postgresql.org>
Reviewed-by: Stephane Tachoires <stephane.tachoires@gmail.com>
Reviewed-by: Jian He <jian.universality@gmail.com>
Reviewed-by: Alexander Korotkov <aekorotkov@gmail.com>
Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com>
Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com>
Reviewed-by: Alexander Lakhin <exclusion@gmail.com>
Reviewed-by: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Reviewed-by: Daniel Gustafsson <dgustafsson@postgresql.org>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Noah Misch <noah@leadboat.com>
---
doc/src/sgml/ddl.sgml | 19 +
doc/src/sgml/ref/alter_table.sgml | 118 +-
src/backend/commands/tablecmds.c | 432 +++++
src/backend/parser/gram.y | 38 +-
src/backend/parser/parse_utilcmd.c | 197 +-
src/backend/partitioning/partbounds.c | 737 +++++++-
src/bin/psql/tab-complete.in.c | 10 +-
src/include/nodes/parsenodes.h | 34 +-
src/include/parser/kwlist.h | 1 +
src/include/partitioning/partbounds.h | 4 +
.../isolation/expected/partition-split.out | 230 +++
src/test/isolation/isolation_schedule | 1 +
src/test/isolation/specs/partition-split.spec | 62 +
.../test_ddl_deparse/expected/alter_table.out | 5 +
.../test_ddl_deparse/sql/alter_table.sql | 4 +
.../test_ddl_deparse/test_ddl_deparse.c | 3 +
src/test/regress/expected/partition_split.out | 1592 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/partition_split.sql | 1134 ++++++++++++
src/tools/pgindent/typedefs.list | 2 +
20 files changed, 4585 insertions(+), 40 deletions(-)
create mode 100644 src/test/isolation/expected/partition-split.out
create mode 100644 src/test/isolation/specs/partition-split.spec
create mode 100644 src/test/regress/expected/partition_split.out
create mode 100644 src/test/regress/sql/partition_split.sql
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 7b90789f87c..cea28c00f8a 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -4764,6 +4764,25 @@ ALTER TABLE measurement
measurement_y2006m03) INTO measurement_y2006q1;
</programlisting>
</para>
+
+ <para>
+ Similarly to merging multiple table partitions, there is an option for
+ splitting a single partition into multiple using the
+ <link linkend="sql-altertable-split-partition"><command>ALTER TABLE ... SPLIT PARTITION</command></link>.
+ This feature could come in handy when one partition grows too big
+ and needs to be split into multiple. It's important to note that
+ this operation is not supported for hash-partitioned tables and acquires
+ an <literal>ACCESS EXCLUSIVE</literal> lock, which could impact high-load
+ systems due to the lock's restrictive nature. For example, we can split
+ the quarter partition back to monthly partitions:
+<programlisting>
+ALTER TABLE measurement SPLIT PARTITION measurement_y2006q1 INTO
+ (PARTITION measurement_y2006m01 FOR VALUES FROM ('2006-01-01') TO ('2006-02-01'),
+ PARTITION measurement_y2006m02 FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'),
+ PARTITION measurement_y2006m03 FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'));
+</programlisting>
+ </para>
+
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index 5cda1c94adb..9abd8037f28 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
+ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
@@ -1258,6 +1262,94 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</listitem>
</varlistentry>
+ <varlistentry id="sql-altertable-split-partition">
+ <term>
+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
+ [, ...])</literal>
+ </term>
+
+ <listitem>
+ <para>
+ This form splits a single partition of the target table into new
+ partitions. Hash-partitioned target table is not supported.
+ Only a simple, non-partitioned partition can be split.
+ If the split partition is the <literal>DEFAULT</literal> partition,
+ one of the new partitions must be <literal>DEFAULT</literal>.
+ If the partitioned table does not have a <literal>DEFAULT</literal>
+ partition, a <literal>DEFAULT</literal> partition can be defined as one
+ of the new partitions.
+ </para>
+
+ <para>
+ The bounds of new partitions should not overlap with those of new or
+ existing partitions (except <replaceable class="parameter">partition_name</replaceable>).
+ The combined bounds of new partitions <literal>
+ <replaceable class="parameter">partition_name1</replaceable>,
+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
+ </literal> should be equal to the bounds of the split partition
+ <replaceable class="parameter">partition_name</replaceable>.
+ One of the new partitions can have the same name as the split partition
+ <replaceable class="parameter">partition_name</replaceable>
+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
+ partition: after the split, the <literal>DEFAULT</literal> partition
+ remains with the same name, but its partition bound changes).
+ </para>
+
+ <para>
+ New partitions will have the same owner as the parent partition.
+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
+ partitions.
+ </para>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
+ table itself as the template to construct new partitions.
+ New partitions will inherit the same table access method, persistence
+ type, and tablespace as the partitioned table.
+ </para>
+
+ <para>
+ Constraints, column defaults, column generation expressions,
+ identity columns, indexes, and triggers are copied from the partitioned
+ table to the new partitions. But extended statistics, security
+ policies, etc, won't be copied from the partitioned table.
+ Indexes and identity columns copied from the partitioned table will be
+ created afterward, once the data has been moved into the new partitions.
+ </para>
+
+ <para>
+ When a partition is split, any objects that depend on this partition,
+ such as constraints, triggers, extended statistics, etc, will be dropped.
+ This occurs because <command>ALTER TABLE SPLIT PARTITION</command> uses
+ the partitioned table itself as the template to reconstruct these
+ objects later.
+ Eventually, we will drop the split partition
+ (using <literal>RESTRICT</literal> mode) too; therefore, if any objects
+ are still dependent on it, <command>ALTER TABLE SPLIT PARTITION</command>
+ would fail (see <xref linkend="ddl-depend"/>).
+ </para>
+
+ <note>
+ <para>
+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
+ lock on the table being split.
+ </para>
+ </note>
+ <note>
+
+ <para>
+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
+ moves data from the split partition into them, which can take a long
+ time. So it is not recommended to use the command for splitting a
+ small fraction of rows out of a very big partition.
+ </para>
+ </note>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
@@ -1265,7 +1357,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
All the forms of <command>ALTER TABLE</command> that act on a single table,
except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
<literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
- and <literal>MERGE PARTITIONS</literal>, can be combined into
+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
+ can be combined into
a list of multiple alterations to be applied together. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command. This is particularly useful with large
@@ -1509,7 +1602,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<listitem>
<para>
The name of the table to attach as a new partition or to detach from this table,
- or the name of the new merged partition.
+ or the name of split partition, or the name of the new merged partition.
</para>
</listitem>
</varlistentry>
@@ -1519,7 +1612,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<term><replaceable class="parameter">partition_name2</replaceable></term>
<listitem>
<para>
- The names of the tables being merged into the new partition.
+ The names of the tables being merged into the new partition or split into
+ new partitions.
</para>
</listitem>
</varlistentry>
@@ -1952,6 +2046,24 @@ ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
</programlisting></para>
+ <para>
+ To split a single partition of the range-partitioned table:
+<programlisting>
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
+</programlisting></para>
+
+ <para>
+ To split a single partition of the list-partitioned table:
+<programlisting>
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+</programlisting></para>
+
<para>
To merge several partitions into one partition of the target table:
<programlisting>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f703293dbc3..953fadb9c6b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -742,6 +742,9 @@ static char GetAttributeStorage(Oid atttypid, const char *storagemode);
static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
PartitionCmd *cmd, AlterTableUtilityContext *context);
+static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
+ Relation rel, PartitionCmd *cmd,
+ AlterTableUtilityContext *context);
/* ----------------------------------------------------------------
* DefineRelation
@@ -4839,6 +4842,7 @@ AlterTableGetLockLevel(List *cmds)
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
cmd_lockmode = AccessExclusiveLock;
break;
@@ -5278,6 +5282,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
pass = AT_PASS_MISC;
break;
case AT_MergePartitions:
+ case AT_SplitPartition:
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5686,6 +5691,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def,
context);
break;
+ case AT_SplitPartition:
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cur_pass, context);
+ Assert(cmd != NULL);
+ Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
+ ATExecSplitPartition(wqueue, tab, rel, (PartitionCmd *) cmd->def,
+ context);
+ break;
default: /* oops */
elog(ERROR, "unrecognized alter table type: %d",
(int) cmd->subtype);
@@ -6728,6 +6741,8 @@ alter_table_type_to_string(AlterTableType cmdtype)
return "DETACH PARTITION ... FINALIZE";
case AT_MergePartitions:
return "MERGE PARTITIONS";
+ case AT_SplitPartition:
+ return "SPLIT PARTITION";
case AT_AddIdentity:
return "ALTER COLUMN ... ADD IDENTITY";
case AT_SetIdentity:
@@ -22905,3 +22920,420 @@ ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel,
/* Restore the userid and security context. */
SetUserIdAndSecContext(save_userid, save_sec_context);
}
+
+/*
+ * Struct with the context of the new partition for inserting rows from the
+ * split partition.
+ */
+typedef struct SplitPartitionContext
+{
+ ExprState *partqualstate; /* expression for checking a slot for a
+ * partition (NULL for DEFAULT partition) */
+ BulkInsertState bistate; /* state of bulk inserts for partition */
+ TupleTableSlot *dstslot; /* slot for inserting row into partition */
+ AlteredTableInfo *tab; /* structure with generated column expressions
+ * and check constraint expressions. */
+ Relation partRel; /* relation for partition */
+} SplitPartitionContext;
+
+/*
+ * createSplitPartitionContext: create context for partition and fill it
+ */
+static SplitPartitionContext *
+createSplitPartitionContext(Relation partRel)
+{
+ SplitPartitionContext *pc;
+
+ pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc->partRel = partRel;
+
+ /*
+ * Prepare a BulkInsertState for table_tuple_insert. The FSM is empty, so
+ * don't bother using it.
+ */
+ pc->bistate = GetBulkInsertState();
+
+ /* Create a destination tuple slot for the new partition. */
+ pc->dstslot = table_slot_create(pc->partRel, NULL);
+
+ return pc;
+}
+
+/*
+ * deleteSplitPartitionContext: delete context for partition
+ */
+static void
+deleteSplitPartitionContext(SplitPartitionContext *pc, List **wqueue, int ti_options)
+{
+ ListCell *ltab;
+
+ ExecDropSingleTupleTableSlot(pc->dstslot);
+ FreeBulkInsertState(pc->bistate);
+
+ table_finish_bulk_insert(pc->partRel, ti_options);
+
+ /*
+ * We don't need to process this pc->partRel so delete the ALTER TABLE
+ * queue of it.
+ */
+ foreach(ltab, *wqueue)
+ {
+ AlteredTableInfo *tab = (AlteredTableInfo *) lfirst(ltab);
+
+ if (tab->relid == RelationGetRelid(pc->partRel))
+ {
+ *wqueue = list_delete_cell(*wqueue, ltab);
+ break;
+ }
+ }
+
+ pfree(pc);
+}
+
+/*
+ * SplitPartitionMoveRows: scan split partition (splitRel) of partitioned table
+ * (rel) and move rows into new partitions.
+ *
+ * New partitions description:
+ * partlist: list of pointers to SinglePartitionSpec structures. It contains
+ * the partition specification details for all new partitions.
+ * newPartRels: list of Relations, new partitions created in
+ * ATExecSplitPartition.
+ */
+static void
+SplitPartitionMoveRows(List **wqueue, Relation rel, Relation splitRel,
+ List *partlist, List *newPartRels)
+{
+ /* The FSM is empty, so don't bother using it. */
+ int ti_options = TABLE_INSERT_SKIP_FSM;
+ CommandId mycid;
+ EState *estate;
+ ListCell *listptr,
+ *listptr2;
+ TupleTableSlot *srcslot;
+ ExprContext *econtext;
+ TableScanDesc scan;
+ Snapshot snapshot;
+ MemoryContext oldCxt;
+ List *partContexts = NIL;
+ TupleConversionMap *tuple_map;
+ SplitPartitionContext *defaultPartCtx = NULL,
+ *pc;
+
+ mycid = GetCurrentCommandId(true);
+
+ estate = CreateExecutorState();
+
+ forboth(listptr, partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+
+ pc = createSplitPartitionContext((Relation) lfirst(listptr2));
+
+ /* Find the work queue entry for the new partition table: newPartRel. */
+ pc->tab = ATGetQueueEntry(wqueue, pc->partRel);
+
+ buildExpressionExecutionStates(pc->tab, pc->partRel, estate);
+
+ if (sps->bound->is_default)
+ {
+ /*
+ * We should not create a structure to check the partition
+ * constraint for the new DEFAULT partition.
+ */
+ defaultPartCtx = pc;
+ }
+ else
+ {
+ List *partConstraint;
+
+ /* Build expression execution states for partition check quals. */
+ partConstraint = get_qual_from_partbound(rel, sps->bound);
+ partConstraint =
+ (List *) eval_const_expressions(NULL,
+ (Node *) partConstraint);
+ /* Make a boolean expression for ExecCheck(). */
+ partConstraint = list_make1(make_ands_explicit(partConstraint));
+
+ /*
+ * Map the vars in the constraint expression from rel's attnos to
+ * splitRel's.
+ */
+ partConstraint = map_partition_varattnos(partConstraint,
+ 1, splitRel, rel);
+
+ pc->partqualstate =
+ ExecPrepareExpr((Expr *) linitial(partConstraint), estate);
+ Assert(pc->partqualstate != NULL);
+ }
+
+ /* Store partition context into a list. */
+ partContexts = lappend(partContexts, pc);
+ }
+
+ econtext = GetPerTupleExprContext(estate);
+
+ /* Create the necessary tuple slot. */
+ srcslot = table_slot_create(splitRel, NULL);
+
+ /*
+ * Map computing for moving attributes of the split partition to the new
+ * partition (for the first new partition, but other new partitions can
+ * use the same map).
+ */
+ pc = (SplitPartitionContext *) lfirst(list_head(partContexts));
+ tuple_map = convert_tuples_by_name(RelationGetDescr(splitRel),
+ RelationGetDescr(pc->partRel));
+
+ /* Scan through the rows. */
+ snapshot = RegisterSnapshot(GetLatestSnapshot());
+ scan = table_beginscan(splitRel, snapshot, 0, NULL);
+
+ /*
+ * Switch to per-tuple memory context and reset it for each tuple
+ * produced, so we don't leak memory.
+ */
+ oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate));
+
+ while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot))
+ {
+ bool found = false;
+ TupleTableSlot *insertslot;
+
+ CHECK_FOR_INTERRUPTS();
+
+ econtext->ecxt_scantuple = srcslot;
+
+ /* Search partition for the current slot, srcslot. */
+ foreach(listptr, partContexts)
+ {
+ pc = (SplitPartitionContext *) lfirst(listptr);
+
+ /* skip DEFAULT partition */
+ if (pc->partqualstate && ExecCheck(pc->partqualstate, econtext))
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ /* Use the DEFAULT partition if it exists. */
+ if (defaultPartCtx)
+ pc = defaultPartCtx;
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CHECK_VIOLATION),
+ errmsg("can not find partition for split partition row"),
+ errtable(splitRel));
+ }
+
+ if (tuple_map)
+ {
+ /* Need to use a map to copy attributes. */
+ insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, pc->dstslot);
+ }
+ else
+ {
+ /* Extract data from the old tuple. */
+ slot_getallattrs(srcslot);
+
+ /* Copy attributes directly. */
+ insertslot = pc->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);
+ }
+
+ /*
+ * Constraints and GENERATED expressions might reference the tableoid
+ * column, so fill tts_tableOid with the desired value. (We must do
+ * this each time, because it gets overwritten with newrel's OID
+ * during storing.)
+ */
+ insertslot->tts_tableOid = RelationGetRelid(pc->partRel);
+
+ /*
+ * Now, evaluate any generated expressions whose inputs come from the
+ * new tuple. We assume these columns won't reference each other, so
+ * that there's no ordering dependency.
+ */
+ evaluateGeneratedExpressionsAndCheckConstraints(pc->tab, pc->partRel,
+ insertslot, econtext);
+
+ /* Write the tuple out to the new relation. */
+ table_tuple_insert(pc->partRel, insertslot, mycid,
+ ti_options, pc->bistate);
+
+ ResetExprContext(econtext);
+ }
+
+ MemoryContextSwitchTo(oldCxt);
+
+ table_endscan(scan);
+ UnregisterSnapshot(snapshot);
+
+ if (tuple_map)
+ free_conversion_map(tuple_map);
+
+ ExecDropSingleTupleTableSlot(srcslot);
+
+ FreeExecutorState(estate);
+
+ foreach_ptr(SplitPartitionContext, spc, partContexts)
+ deleteSplitPartitionContext(spc, wqueue, ti_options);
+}
+
+/*
+ * ALTER TABLE <name> SPLIT PARTITION <partition-name> INTO <partition-list>
+ */
+static void
+ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
+ PartitionCmd *cmd, AlterTableUtilityContext *context)
+{
+ Relation splitRel;
+ Oid splitRelOid;
+ ListCell *listptr,
+ *listptr2;
+ bool isSameName = false;
+ char tmpRelName[NAMEDATALEN];
+ List *newPartRels = NIL;
+ ObjectAddress object;
+ Oid defaultPartOid;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true));
+
+ /*
+ * Partition is already locked in the transformPartitionCmdForSplit
+ * function.
+ */
+ splitRel = table_openrv(cmd->name, NoLock);
+
+ splitRelOid = RelationGetRelid(splitRel);
+
+ /* Check descriptions of new partitions. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Oid existingRelid;
+
+ /* Look up the existing relation by the new partition name. */
+ RangeVarGetAndCheckCreationNamespace(sps->name, NoLock, &existingRelid);
+
+ /*
+ * This would fail later on anyway if the relation already exists. But
+ * by catching it here, we can emit a nicer error message.
+ */
+ if (existingRelid == splitRelOid && !isSameName)
+ /* One new partition can have the same name as a split partition. */
+ isSameName = true;
+ else if (OidIsValid(existingRelid))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("relation \"%s\" already exists", sps->name->relname));
+ }
+
+ /* Detach the split partition. */
+ detachPartitionTable(rel, splitRel, defaultPartOid);
+
+ /*
+ * Perform a preliminary check to determine whether it's safe to drop the
+ * split partition before we actually do so later. After merging rows into
+ * the new partitions via SplitPartitionMoveRows, all old partitions need
+ * to be dropped. However, since the drop behavior is DROP_RESTRICT and
+ * the merge process (SplitPartitionMoveRows) can be time-consuming,
+ * performing an early check on the drop eligibility of old partitions is
+ * preferable.
+ */
+ object.objectId = splitRelOid;
+ object.classId = RelationRelationId;
+ object.objectSubId = 0;
+ performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ /*
+ * If a new partition has the same name as the split partition, then we
+ * should rename the split partition to reuse its name.
+ */
+ if (isSameName)
+ {
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible for renaming.
+ */
+ CommandCounterIncrement();
+ /* Rename partition. */
+ sprintf(tmpRelName, "split-%u-%X-tmp", RelationGetRelid(rel), MyProcPid);
+ RenameRelationInternal(splitRelOid, tmpRelName, true, false);
+
+ /*
+ * We must bump the command counter to make the split partition tuple
+ * visible after renaming.
+ */
+ CommandCounterIncrement();
+ }
+
+ /* Create new partitions (like a split partition), without indexes. */
+ foreach_node(SinglePartitionSpec, sps, cmd->partlist)
+ {
+ Relation newPartRel;
+
+ newPartRel = createPartitionTable(wqueue, sps->name, rel,
+ splitRel->rd_rel->relowner);
+ newPartRels = lappend(newPartRels, newPartRel);
+ }
+
+ /*
+ * Switch to the table owner's userid, so that any index functions are run
+ * as that user. Also, lockdown security-restricted operations and
+ * arrange to make GUC variable changes local to this command.
+ *
+ * Need to do it after determining the namespace in the
+ * createPartitionTable() call.
+ */
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(splitRel->rd_rel->relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+ RestrictSearchPath();
+
+ /* Copy data from the split partition to the new partitions. */
+ SplitPartitionMoveRows(wqueue, rel, splitRel, cmd->partlist, newPartRels);
+ /* Keep the lock until commit. */
+ table_close(splitRel, NoLock);
+
+ /* Attach new partitions to the partitioned table. */
+ forboth(listptr, cmd->partlist, listptr2, newPartRels)
+ {
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ Relation newPartRel = (Relation) lfirst(listptr2);
+
+ /*
+ * wqueue = NULL: verification for each cloned constraint is not
+ * needed.
+ */
+ attachPartitionTable(NULL, rel, newPartRel, sps->bound);
+ /* Keep the lock until commit. */
+ table_close(newPartRel, NoLock);
+ }
+
+ /* Drop the split partition. */
+ object.classId = RelationRelationId;
+ object.objectId = splitRelOid;
+ object.objectSubId = 0;
+ /* Probably DROP_CASCADE is not needed. */
+ performDeletion(&object, DROP_RESTRICT, 0);
+
+ /* Roll back any GUC changes executed by index functions. */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore the userid and security context. */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 562f11d6677..28f4e11e30f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -262,6 +262,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
PartitionElem *partelem;
PartitionSpec *partspec;
PartitionBoundSpec *partboundspec;
+ SinglePartitionSpec *singlepartspec;
RoleSpec *rolespec;
PublicationObjSpec *publicationobjectspec;
PublicationAllObjSpec *publicationallobjectspec;
@@ -648,6 +649,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
+%type <singlepartspec> SinglePartitionSpec
+%type <list> partitions_list
%type <list> hash_partbound
%type <defelt> hash_partbound_elem
@@ -777,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
- SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SOURCE SQL_P STABLE STANDALONE_P
+ SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SPLIT SOURCE SQL_P STABLE STANDALONE_P
START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING_P STRIP_P
SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P SYSTEM_USER
@@ -2385,6 +2388,23 @@ alter_table_cmds:
| alter_table_cmds ',' alter_table_cmd { $$ = lappend($1, $3); }
;
+partitions_list:
+ SinglePartitionSpec { $$ = list_make1($1); }
+ | partitions_list ',' SinglePartitionSpec { $$ = lappend($1, $3); }
+ ;
+
+SinglePartitionSpec:
+ PARTITION qualified_name PartitionBoundSpec
+ {
+ SinglePartitionSpec *n = makeNode(SinglePartitionSpec);
+
+ n->name = $2;
+ n->bound = $3;
+
+ $$ = n;
+ }
+ ;
+
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name PartitionBoundSpec
@@ -2429,6 +2449,20 @@ partition_cmd:
n->def = (Node *) cmd;
$$ = (Node *) n;
}
+ /* ALTER TABLE <name> SPLIT PARTITION <partition_name> INTO () */
+ | SPLIT PARTITION qualified_name INTO '(' partitions_list ')'
+ {
+ AlterTableCmd *n = makeNode(AlterTableCmd);
+ PartitionCmd *cmd = makeNode(PartitionCmd);
+
+ n->subtype = AT_SplitPartition;
+ cmd->name = $3;
+ cmd->bound = NULL;
+ cmd->partlist = $6;
+ cmd->concurrent = false;
+ n->def = (Node *) cmd;
+ $$ = (Node *) n;
+ }
/* ALTER TABLE <name> MERGE PARTITIONS () INTO <partition_name> */
| MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name
{
@@ -18126,6 +18160,7 @@ unreserved_keyword:
| SKIP
| SNAPSHOT
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
@@ -18768,6 +18803,7 @@ bare_label_keyword:
| SNAPSHOT
| SOME
| SOURCE
+ | SPLIT
| SQL_P
| STABLE
| STANDALONE_P
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index bf02e38785d..375b40b29af 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -137,7 +137,7 @@ static void transformConstraintAttrs(CreateStmtContext *cxt,
List *constraintList);
static void transformColumnType(CreateStmtContext *cxt, ColumnDef *column);
static void setSchemaName(const char *context_schema, char **stmt_schema_name);
-static void transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd);
+static void transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound);
static List *transformPartitionRangeBounds(ParseState *pstate, List *blist,
Relation parent);
static void validateInfiniteBounds(ParseState *pstate, List *blist);
@@ -3515,9 +3515,11 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString,
/*
* checkPartition
* Check whether partRelOid is a leaf partition of the parent table (rel).
+ * isMerge: true indicates the operation is "ALTER TABLE ... MERGE PARTITIONS";
+ * false indicates the operation is "ALTER TABLE ... SPLIT PARTITION".
*/
static void
-checkPartition(Relation rel, Oid partRelOid)
+checkPartition(Relation rel, Oid partRelOid, bool isMerge)
{
Relation partRel;
@@ -3527,25 +3529,176 @@ checkPartition(Relation rel, Oid partRelOid)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (!partRel->rd_rel->relispartition)
ereport(ERROR,
errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a partition of partitioned table \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
- errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions"));
+ isMerge
+ ? errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")
+ : errhint("ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions"));
table_close(partRel, NoLock);
}
+/*
+ * transformPartitionCmdForSplit -
+ * analyze the ALTER TABLE ... SPLIT PARTITION command
+ *
+ * For each new partition, sps->bound is set to the transformed value of bound.
+ * Does checks for bounds of new partitions.
+ */
+static void
+transformPartitionCmdForSplit(CreateStmtContext *cxt, PartitionCmd *partcmd)
+{
+ Relation parent = cxt->rel;
+ PartitionKey key;
+ char strategy;
+ Oid splitPartOid;
+ Oid defaultPartOid;
+ int default_index = -1;
+ bool isSplitPartDefault;
+ ListCell *listptr,
+ *listptr2;
+ List *splitlist;
+
+ splitlist = partcmd->partlist;
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+ defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ /* Transform partition bounds for all partitions in the list: */
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ cxt->partbound = NULL;
+ transformPartitionCmd(cxt, sps->bound);
+ /* Assign the transformed value of the partition bound. */
+ sps->bound = cxt->partbound;
+ }
+
+ /*
+ * Open and lock the partition, check ownership along the way. We need to
+ * use AccessExclusiveLock here because this split partition will be
+ * detached, then dropped in ATExecSplitPartition.
+ */
+ splitPartOid = RangeVarGetRelidExtended(partcmd->name, AccessExclusiveLock,
+ 0, RangeVarCallbackOwnsRelation,
+ NULL);
+
+ checkPartition(parent, splitPartOid, false);
+
+ switch (strategy)
+ {
+ case PARTITION_STRATEGY_LIST:
+ case PARTITION_STRATEGY_RANGE:
+ {
+ foreach_node(SinglePartitionSpec, sps, splitlist)
+ {
+ if (sps->bound->is_default)
+ {
+ if (default_index != -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("DEFAULT partition should be one"),
+ parser_errposition(cxt->pstate, sps->name->location));
+
+ default_index = foreach_current_index(sps);
+ }
+ }
+ }
+ break;
+
+ case PARTITION_STRATEGY_HASH:
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partition of hash-partitioned table cannot be split"));
+ break;
+
+ default:
+ elog(ERROR, "unexpected partition strategy: %d",
+ (int) key->strategy);
+ break;
+ }
+
+ /* isSplitPartDefault: is the being split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ if (isSplitPartDefault && default_index == -1)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errhint("To split DEFAULT partition one of the new partition msut be DEFAULT"),
+ parser_errposition(cxt->pstate, ((SinglePartitionSpec *) linitial(splitlist))->name->location));
+
+ /*
+ * If the partition being split is not the DEFAULT partition, but the
+ * DEFAULT partition exists, then none of the resulting split partitions
+ * can be the DEFAULT.
+ */
+ if (!isSplitPartDefault && (default_index != -1) && OidIsValid(defaultPartOid))
+ {
+ SinglePartitionSpec *spsDef =
+ (SinglePartitionSpec *) list_nth(splitlist, default_index);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split non-DEFAULT partition \"%s\"",
+ get_rel_name(splitPartOid)),
+ errmsg("new partition cannot be DEFAULT because DEFAULT partition \"%s\" already exists",
+ get_rel_name(defaultPartOid)),
+ parser_errposition(cxt->pstate, spsDef->name->location));
+ }
+
+ foreach(listptr, splitlist)
+ {
+ Oid nspid;
+ SinglePartitionSpec *sps = (SinglePartitionSpec *) lfirst(listptr);
+ RangeVar *name = sps->name;
+
+ nspid = RangeVarGetCreationNamespace(sps->name);
+
+ /* Partitions in the list should have different names. */
+ for_each_cell(listptr2, splitlist, lnext(splitlist, listptr))
+ {
+ Oid nspid2;
+ SinglePartitionSpec *sps2 = (SinglePartitionSpec *) lfirst(listptr2);
+ RangeVar *name2 = sps2->name;
+
+ if (equal(name, name2))
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+
+ nspid2 = RangeVarGetCreationNamespace(sps2->name);
+
+ if (nspid2 == nspid && strcmp(name->relname, name2->relname) == 0)
+ ereport(ERROR,
+ errcode(ERRCODE_DUPLICATE_TABLE),
+ errmsg("partition with name \"%s\" is already used", name->relname),
+ parser_errposition(cxt->pstate, name2->location));
+ }
+ }
+
+ /* Then we should check partitions with transformed bounds. */
+ check_partitions_for_split(parent, splitPartOid, splitlist, cxt->pstate);
+}
+
+
/*
* transformPartitionCmdForMerge -
* analyze the ALTER TABLE ... MERGE PARTITIONS command
@@ -3622,7 +3775,7 @@ transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd)
parser_errposition(cxt->pstate, name->location));
}
- checkPartition(parent, partOid);
+ checkPartition(parent, partOid, true);
partOids = lappend_oid(partOids, partOid);
}
@@ -3910,8 +4063,8 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
{
PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
- transformPartitionCmd(&cxt, partcmd);
- /* assign transformed value of the partition bound */
+ transformPartitionCmd(&cxt, partcmd->bound);
+ /* assign the transformed value of the partition bound */
partcmd->bound = cxt.partbound;
}
@@ -3932,6 +4085,20 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
break;
}
+ case AT_SplitPartition:
+ {
+ PartitionCmd *partcmd = (PartitionCmd *) cmd->def;
+
+ if (list_length(partcmd->partlist) < 2)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("list of new partitions should contain at least two partitions"));
+
+ transformPartitionCmdForSplit(&cxt, partcmd);
+ newcmds = lappend(newcmds, cmd);
+ break;
+ }
+
default:
/*
@@ -4362,13 +4529,13 @@ setSchemaName(const char *context_schema, char **stmt_schema_name)
/*
* transformPartitionCmd
- * Analyze the ATTACH/DETACH PARTITION command
+ * Analyze the ATTACH/DETACH/SPLIT PARTITION command
*
- * In case of the ATTACH PARTITION command, cxt->partbound is set to the
- * transformed value of cmd->bound.
+ * In case of the ATTACH/SPLIT PARTITION command, cxt->partbound is set to the
+ * transformed value of bound.
*/
static void
-transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
+transformPartitionCmd(CreateStmtContext *cxt, PartitionBoundSpec *bound)
{
Relation parentRel = cxt->rel;
@@ -4377,9 +4544,9 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
case RELKIND_PARTITIONED_TABLE:
/* transform the partition bound, if any */
Assert(RelationGetPartitionKey(parentRel) != NULL);
- if (cmd->bound != NULL)
+ if (bound != NULL)
cxt->partbound = transformPartitionBound(cxt->pstate, parentRel,
- cmd->bound);
+ bound);
break;
case RELKIND_PARTITIONED_INDEX:
@@ -4387,7 +4554,7 @@ transformPartitionCmd(CreateStmtContext *cxt, PartitionCmd *cmd)
* A partitioned index cannot have a partition bound set. ALTER
* INDEX prevents that with its grammar, but not ALTER TABLE.
*/
- if (cmd->bound != NULL)
+ if (bound != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("\"%s\" is not a partitioned table",
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b82b29de8f7..b7f90ae109d 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -17,6 +17,7 @@
#include "access/relation.h"
#include "access/table.h"
#include "access/tableam.h"
+#include "catalog/namespace.h"
#include "catalog/partition.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
@@ -4974,15 +4975,22 @@ satisfies_hash_partition(PG_FUNCTION_ARGS)
*
* (function for BY RANGE partitioning)
*
- * This is a helper function for calculate_partition_bound_for_merge(). This
- * function compares the upper bound of first_bound and the lower bound of
- * second_bound. These bounds should be equal.
+ * This is a helper function for check_partitions_for_split() and
+ * calculate_partition_bound_for_merge(). This function compares the upper
+ * bound of first_bound and the lower bound of second_bound. These bounds
+ * should be equal except when "defaultPart == true" (this means that one of
+ * the split partitions is DEFAULT). In this case, the upper bound of
+ * first_bound can be less than the lower bound of second_bound because
+ * the space between these bounds will be included in the DEFAULT partition.
*
* parent: partitioned table
* first_name: name of the first partition
* first_bound: bound of the first partition
* second_name: name of the second partition
* second_bound: bound of the second partition
+ * defaultPart: true if one of the new partitions is DEFAULT
+ * is_merge: true ndicates the operation is MERGE PARTITIONS;
+ * false indicates the operation is SPLIT PARTITION.
* pstate: pointer to ParseState struct for determining error position
*/
static void
@@ -4991,6 +4999,8 @@ check_two_partitions_bounds_range(Relation parent,
PartitionBoundSpec *first_bound,
RangeVar *second_name,
PartitionBoundSpec *second_bound,
+ bool defaultPart,
+ bool is_merge,
ParseState *pstate)
{
PartitionKey key = RelationGetPartitionKey(parent);
@@ -5012,18 +5022,28 @@ check_two_partitions_bounds_range(Relation parent,
key->partcollation,
second_lower->datums, second_lower->kind,
false, first_upper);
- if (cmpval)
+ if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0))
{
PartitionRangeDatum *datum = linitial(second_bound->lowerdatums);
- ereport(ERROR,
- errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
- errmsg("can not merge partition \"%s\" together with partition \"%s\"",
- second_name->relname, first_name->relname),
- errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
- second_name->relname, first_name->relname),
- errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
- parser_errposition(pstate, datum->location));
+ if (is_merge)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not merge partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("can not split to partition \"%s\" together with partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"",
+ second_name->relname, first_name->relname),
+ errhint("ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent."),
+ parser_errposition(pstate, datum->location));
}
}
@@ -5126,6 +5146,8 @@ calculate_partition_bound_for_merge(Relation parent,
(PartitionBoundSpec *) list_nth(bounds, prev_index),
(RangeVar *) list_nth(partNames, index),
(PartitionBoundSpec *) list_nth(bounds, index),
+ false,
+ true,
pstate);
}
@@ -5164,3 +5186,694 @@ calculate_partition_bound_for_merge(Relation parent,
(int) key->strategy);
}
}
+
+/*
+ * partitions_listdatum_intersection
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function compares lists of values for different partitions.
+ * Return a list that contains *one* cell that is present in both list1 and
+ * list2. The returned list is freshly allocated via palloc(), but the
+ * cells themselves point to the same objects as the cells of the
+ * input lists.
+ *
+ * Currently, there is no need to collect all common partition datums from the
+ * two lists.
+ */
+static List *
+partitions_listdatum_intersection(FmgrInfo *partsupfunc, Oid *partcollation,
+ const List *list1, const List *list2)
+{
+ List *result = NIL;
+
+ if (list1 == NIL || list2 == NIL)
+ return result;
+
+ foreach_node(Const, val1, list1)
+ {
+ bool isnull1 = val1->constisnull;
+
+ foreach_node(Const, val2, list2)
+ {
+ if (val2->constisnull)
+ {
+ if (isnull1)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ continue;
+ }
+ else if (isnull1)
+ continue;
+
+ /* Compare two datum values. */
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val1->constvalue,
+ val2->constvalue)) == 0)
+ {
+ result = lappend(result, val1);
+ return result;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * check_partitions_not_overlap_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * This is a helper function for check_partitions_for_split().
+ * Checks that the values of the new partitions do not overlap.
+ *
+ * parent: partitioned table
+ * parts: array of SinglePartitionSpec structs with info about split partitions
+ * nparts: size of array "parts"
+ */
+static void
+check_partitions_not_overlap_list(Relation parent,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key PG_USED_FOR_ASSERTS_ONLY = RelationGetPartitionKey(parent);
+ int i,
+ j;
+ SinglePartitionSpec *sps1,
+ *sps2;
+ List *overlap;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ for (i = 0; i < nparts; i++)
+ {
+ sps1 = parts[i];
+
+ for (j = i + 1; j < nparts; j++)
+ {
+ sps2 = parts[j];
+
+ overlap = partitions_listdatum_intersection(&key->partsupfunc[0],
+ key->partcollation,
+ sps1->bound->listdatums,
+ sps2->bound->listdatums);
+ if (list_length(overlap) > 0)
+ {
+ Const *val = (Const *) linitial_node(Const, overlap);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another new partition \"%s\"",
+ sps1->name->relname, sps2->name->relname),
+ parser_errposition(pstate, exprLocation((Node *) val)));
+ }
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_range
+ *
+ * (function for BY RANGE partitioning)
+ *
+ * Checks that bounds of new partition "spec" are inside bounds of split
+ * partition (with Oid splitPartOid). If first=true (this means that "spec" is
+ * the first of the new partitions), then the lower bound of "spec" should be
+ * equal (or greater than or equal in case defaultPart=true) to the lower
+ * bound of the split partition. If last=true (this means that "spec" is the
+ * last of the new partitions), then the upper bound of "spec" should be
+ * equal (or less than or equal in case defaultPart=true) to the upper bound
+ * of the split partition.
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * first: true iff the new partition "spec" is the first of the
+ * new partitions
+ * last: true iff the new partition "spec" is the last of the
+ * new partitions
+ * defaultPart: true iff new partitions contain the DEFAULT partition
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_range(Relation parent,
+ char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ bool first,
+ bool last,
+ bool defaultPart,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionRangeBound *lower,
+ *upper;
+ int cmpval;
+
+ Assert(key->strategy == PARTITION_STRATEGY_RANGE);
+ Assert(spec->strategy == PARTITION_STRATEGY_RANGE);
+
+ lower = make_one_partition_rbound(key, -1, spec->lowerdatums, true);
+ upper = make_one_partition_rbound(key, -1, spec->upperdatums, false);
+
+ /*
+ * First, check if the resulting range would be empty with the specified
+ * lower and upper bounds. partition_rbound_cmp cannot return zero here,
+ * since the lower-bound flags are different.
+ */
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, upper);
+ Assert(cmpval != 0);
+ if (cmpval > 0)
+ {
+ /* Point to the problematic key in the lower datums list. */
+ PartitionRangeDatum *datum = list_nth(spec->lowerdatums, cmpval - 1);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("empty range bound specified for partition \"%s\"",
+ relname),
+ errdetail("Specified lower bound %s is greater than or equal to upper bound %s.",
+ get_range_partbound_string(spec->lowerdatums),
+ get_range_partbound_string(spec->upperdatums)),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+
+ /*
+ * Need to check first and last partitions (from the set of new
+ * partitions)
+ */
+ if (first || last)
+ {
+ PartitionBoundSpec *split_spec = get_partition_bound_spec(splitPartOid);
+ PartitionRangeDatum *datum;
+
+ if (first)
+ {
+ PartitionRangeBound *split_lower;
+
+ split_lower = make_one_partition_rbound(key, -1, split_spec->lowerdatums, true);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ lower->datums, lower->kind,
+ true, split_lower);
+ if (cmpval != 0)
+ datum = list_nth(spec->lowerdatums, abs(cmpval) - 1);
+
+ /*
+ * The lower bound of "spec" must equal the lower bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's lower bound to
+ * be greater than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is not equal to lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval < 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("lower bound of partition \"%s\" is less than lower bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else
+ {
+ PartitionRangeBound *split_upper;
+
+ split_upper = make_one_partition_rbound(key, -1, split_spec->upperdatums, false);
+
+ cmpval = partition_rbound_cmp(key->partnatts,
+ key->partsupfunc,
+ key->partcollation,
+ upper->datums, upper->kind,
+ false, split_upper);
+ if (cmpval != 0)
+ datum = list_nth(spec->upperdatums, abs(cmpval) - 1);
+
+ /*
+ * The upper bound of "spec" must equal the upper bound of the
+ * split partition. However, if one of the new partitions is
+ * DEFAULT, then it is ok for the new partition's upper bound to
+ * be less than that of the split partition.
+ */
+ if (!defaultPart)
+ {
+ if (cmpval != 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is not equal to upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ else if (cmpval > 0)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("upper bound of partition \"%s\" is greater than upper bound of split partition \"%s\"",
+ relname,
+ get_rel_name(splitPartOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"),
+ parser_errposition(pstate, exprLocation((Node *) datum)));
+ }
+ }
+}
+
+/*
+ * check_partition_bounds_for_split_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that the bounds of the new partition are inside the bounds of the
+ * split partition (with Oid splitPartOid).
+ *
+ * parent: partitioned table
+ * relname: name of the new partition
+ * spec: bounds specification of the new partition
+ * splitPartOid: split partition Oid
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_partition_bounds_for_split_list(Relation parent, char *relname,
+ PartitionBoundSpec *spec,
+ Oid splitPartOid,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int with = -1;
+ bool overlap = false;
+ int overlap_location = -1;
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+ Assert(spec->strategy == PARTITION_STRATEGY_LIST);
+ Assert(boundinfo && boundinfo->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Search each value of the new partition "spec" in the existing
+ * partitions. All of them should be in the split partition (with Oid
+ * splitPartOid).
+ */
+ foreach_node(Const, val, spec->listdatums)
+ {
+ overlap_location = exprLocation((Node *) val);
+ if (!val->constisnull)
+ {
+ int offset;
+ bool equal;
+
+ offset = partition_list_bsearch(&key->partsupfunc[0],
+ key->partcollation,
+ boundinfo,
+ val->constvalue,
+ &equal);
+ if (offset >= 0 && equal)
+ {
+ with = boundinfo->indexes[offset];
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have this value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+ else if (partition_bound_accepts_nulls(boundinfo))
+ {
+ with = boundinfo->null_index;
+ if (partdesc->oids[with] != splitPartOid)
+ {
+ overlap = true;
+ break;
+ }
+ }
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" cannot have NULL value because split partition \"%s\" does not have",
+ relname,
+ get_rel_name(splitPartOid)),
+ parser_errposition(pstate, overlap_location));
+ }
+
+ if (overlap)
+ {
+ Assert(with >= 0);
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partition \"%s\" would overlap with another (not split) partition \"%s\"",
+ relname, get_rel_name(partdesc->oids[with])),
+ parser_errposition(pstate, overlap_location));
+ }
+}
+
+/*
+ * find_value_in_new_partitions_list
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Function returns true iff any of the new partitions contains the value
+ * "value".
+ *
+ * partsupfunc: information about the comparison function associated with
+ * the partition key
+ * partcollation: partitioning collation
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * value: the value that we are looking for
+ * isnull: true if the value that we are looking for is NULL
+ */
+static bool
+find_value_in_new_partitions_list(FmgrInfo *partsupfunc,
+ Oid *partcollation,
+ SinglePartitionSpec **parts,
+ int nparts,
+ Datum value,
+ bool isnull)
+{
+ for (int i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = parts[i];
+
+ foreach_node(Const, val, sps->bound->listdatums)
+ {
+ if (isnull && val->constisnull)
+ return true;
+
+ if (!isnull && !val->constisnull)
+ {
+ if (DatumGetInt32(FunctionCall2Coll(&partsupfunc[0],
+ partcollation[0],
+ val->constvalue,
+ value)) == 0)
+ return true;
+ }
+ }
+ }
+ return false;
+}
+
+/*
+ * check_parent_values_in_new_partitions
+ *
+ * (function for BY LIST partitioning)
+ *
+ * Checks that all values of split partition (with Oid partOid) are contained
+ * in new partitions.
+ *
+ * parent: partitioned table
+ * partOid: split partition Oid
+ * parts: pointer to an array with new partition descriptions
+ * nparts: number of new partitions
+ * pstate: pointer to ParseState struct to determine error position
+ */
+static void
+check_parent_values_in_new_partitions(Relation parent,
+ Oid partOid,
+ SinglePartitionSpec **parts,
+ int nparts,
+ ParseState *pstate)
+{
+ PartitionKey key = RelationGetPartitionKey(parent);
+ PartitionDesc partdesc = RelationGetPartitionDesc(parent, false);
+ PartitionBoundInfo boundinfo = partdesc->boundinfo;
+ int i;
+ bool found = true;
+ Datum datum = PointerGetDatum(NULL);
+
+ Assert(key->strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Special processing for NULL value. Search for a NULL value if the split
+ * partition (partOid) contains it.
+ */
+ if (partition_bound_accepts_nulls(boundinfo) &&
+ partdesc->oids[boundinfo->null_index] == partOid)
+ {
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, true))
+ found = false;
+ }
+
+ if (!found)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ "NULL",
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+
+ /*
+ * Search all values of split partition with partOid in the PartitionDesc
+ * of partitioned table.
+ */
+ for (i = 0; i < boundinfo->ndatums; i++)
+ {
+ if (partdesc->oids[boundinfo->indexes[i]] == partOid)
+ {
+ /* We found the value that the split partition contains. */
+ datum = boundinfo->datums[i][0];
+ if (!find_value_in_new_partitions_list(&key->partsupfunc[0],
+ key->partcollation, parts, nparts, datum, false))
+ {
+ found = false;
+ break;
+ }
+ }
+ }
+
+ if (!found)
+ {
+ Const *notFoundVal;
+
+ /*
+ * Make a Const for getting the string representation of the missing
+ * value.
+ */
+ notFoundVal = makeConst(key->parttypid[0],
+ key->parttypmod[0],
+ key->parttypcoll[0],
+ key->parttyplen[0],
+ datum,
+ false, /* isnull */
+ key->parttypbyval[0]);
+
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
+ errmsg("new partitions combined partition bounds do not contain value (%s) but split partition \"%s\" does",
+ deparse_expression((Node *) notFoundVal, NIL, false, false),
+ get_rel_name(partOid)),
+ errhint("%s require combined bounds of new partitions must exactly match the bound of the split partition",
+ "ALTER TABLE ... SPLIT PARTITION"));
+ }
+}
+
+/*
+ * check_partitions_for_split
+ *
+ * Checks new partitions for the SPLIT PARTITION command:
+ * 1. Bounds of new partitions should not overlap with new and existing
+ * partitions.
+ * 2. In the case when new or existing partitions contain the DEFAULT
+ * partition, new partitions can have any bounds inside the split partition
+ * bound (can be spaces between partition bounds).
+ * 3. In case new partitions don't contain the DEFAULT partition and the
+ * partitioned table does not have the DEFAULT partition, the following
+ * should be true: the sum of the bounds of new partitions should be equal
+ & to the bound of the split partition.
+ *
+ * parent: partitioned table
+ * splitPartOid: split partition Oid
+ * partlist: list of new partitions after partition split
+ * pstate: pointer to ParseState struct for determine error position
+ */
+void
+check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate)
+{
+ PartitionKey key;
+ char strategy;
+ Oid defaultPartOid;
+ bool isSplitPartDefault;
+ bool createDefaultPart = false;
+ int default_index = -1;
+ int i;
+ SinglePartitionSpec **new_parts;
+ SinglePartitionSpec *spsPrev = NULL;
+
+ /*
+ * nparts counts the number of split partitions, but it exclude the
+ * default partition.
+ */
+ int nparts = 0;
+
+ key = RelationGetPartitionKey(parent);
+ strategy = get_partition_strategy(key);
+
+ defaultPartOid =
+ get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true));
+
+ Assert(strategy == PARTITION_STRATEGY_RANGE ||
+ strategy == PARTITION_STRATEGY_LIST);
+
+ /*
+ * Make an array new_parts with new partitions except the DEFAULT
+ * partition.
+ */
+ new_parts = (SinglePartitionSpec **)
+ palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+
+ /* isSplitPartDefault flag: is split partition a DEFAULT partition? */
+ isSplitPartDefault = (defaultPartOid == splitPartOid);
+
+ foreach_node(SinglePartitionSpec, sps, partlist)
+ {
+ if (sps->bound->is_default)
+ default_index = foreach_current_index(sps);
+ else
+ new_parts[nparts++] = sps;
+ }
+
+ /* An indicator that the DEFAULT partition will be created. */
+ if (default_index != -1)
+ {
+ createDefaultPart = true;
+ Assert(nparts == list_length(partlist) - 1);
+ }
+
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ PartitionRangeBound **lower_bounds;
+ SinglePartitionSpec **tmp_new_parts;
+
+ /*
+ * To simplify the check for ranges of new partitions, we need to sort
+ * all partitions in ascending order of their bounds (we compare the
+ * lower bound only).
+ */
+ lower_bounds = (PartitionRangeBound **)
+ palloc0(nparts * sizeof(PartitionRangeBound *));
+
+ /* Create an array of lower bounds. */
+ for (i = 0; i < nparts; i++)
+ {
+ lower_bounds[i] = make_one_partition_rbound(key, i,
+ new_parts[i]->bound->lowerdatums, true);
+ }
+
+ /* Sort the array of lower bounds. */
+ qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *),
+ qsort_partition_rbound_cmp, (void *) key);
+
+ /* Reorder the array of partitions. */
+ tmp_new_parts = new_parts;
+ new_parts = (SinglePartitionSpec **)
+ palloc0(nparts * sizeof(SinglePartitionSpec *));
+ for (i = 0; i < nparts; i++)
+ new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
+
+ pfree(tmp_new_parts);
+ pfree(lower_bounds);
+ }
+
+ for (i = 0; i < nparts; i++)
+ {
+ SinglePartitionSpec *sps = new_parts[i];
+
+ if (isSplitPartDefault)
+ {
+ /*
+ * When the split partition is the DEFAULT partition, we can use
+ * any free ranges - as when creating a new partition.
+ */
+ check_new_partition_bound(sps->name->relname, parent, sps->bound,
+ pstate);
+ }
+ else
+ {
+ /*
+ * Checks that the bounds of the current partition are inside the
+ * bounds of the split partition. For range partitioning: checks
+ * that the upper bound of the previous partition is equal to the
+ * lower bound of the current partition. For list partitioning:
+ * checks that the split partition contains all values of the
+ * current partition.
+ */
+ if (strategy == PARTITION_STRATEGY_RANGE)
+ {
+ bool first = (i == 0);
+ bool last = (i == (nparts - 1));
+
+ check_partition_bounds_for_split_range(parent, sps->name->relname, sps->bound,
+ splitPartOid, first, last,
+ createDefaultPart, pstate);
+ }
+ else
+ check_partition_bounds_for_split_list(parent, sps->name->relname,
+ sps->bound, splitPartOid, pstate);
+ }
+
+ /* Ranges of new partitions should not overlap. */
+ if (strategy == PARTITION_STRATEGY_RANGE && spsPrev)
+ check_two_partitions_bounds_range(parent, spsPrev->name, spsPrev->bound,
+ sps->name, sps->bound,
+ createDefaultPart,
+ false,
+ pstate);
+
+ spsPrev = sps;
+ }
+
+ if (strategy == PARTITION_STRATEGY_LIST)
+ {
+ /* Values of new partitions should not overlap. */
+ check_partitions_not_overlap_list(parent, new_parts, nparts,
+ pstate);
+
+ /*
+ * Need to check that all values of the split partition are contained
+ * in the new partitions. Skip this check if the DEFAULT partition
+ * exists.
+ */
+ if (!createDefaultPart)
+ check_parent_values_in_new_partitions(parent, splitPartOid,
+ new_parts, nparts, pstate);
+ }
+
+ pfree(new_parts);
+}
diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 3176fd92ad3..b1ff6f6cd94 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2773,7 +2773,7 @@ match_previous_words(int pattern_id,
"OWNER TO", "SET", "VALIDATE CONSTRAINT",
"REPLICA IDENTITY", "ATTACH PARTITION",
"DETACH PARTITION", "FORCE ROW LEVEL SECURITY",
- "MERGE PARTITIONS (",
+ "SPLIT PARTITION", "MERGE PARTITIONS (",
"OF", "NOT OF");
/* ALTER TABLE xxx ADD */
else if (Matches("ALTER", "TABLE", MatchAny, "ADD"))
@@ -3036,10 +3036,10 @@ match_previous_words(int pattern_id,
COMPLETE_WITH("FROM (", "IN (", "WITH (");
/*
- * If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
+ * If we have ALTER TABLE <foo> DETACH|SPLIT PARTITION, provide a list of
* partitions of <foo>.
*/
- else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION"))
+ else if (Matches("ALTER", "TABLE", MatchAny, "DETACH|SPLIT", "PARTITION"))
{
set_completion_reference(prev3_wd);
COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table);
@@ -3047,6 +3047,10 @@ match_previous_words(int pattern_id,
else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny))
COMPLETE_WITH("CONCURRENTLY", "FINALIZE");
+ /* ALTER TABLE <name> SPLIT PARTITION <name> */
+ else if (Matches("ALTER", "TABLE", MatchAny, "SPLIT", "PARTITION", MatchAny))
+ COMPLETE_WITH("INTO ( PARTITION");
+
/* ALTER TABLE <name> MERGE PARTITIONS ( */
else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "("))
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index e43a1f946a9..bc7adba4a0f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -965,17 +965,40 @@ typedef struct PartitionRangeDatum
ParseLoc location; /* token location, or -1 if unknown */
} PartitionRangeDatum;
+/*
+ * PartitionDesc - info about a single partition for the 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 and for
- * ALTER TABLE MERGE PARTITIONS commands
+ * ALTER TABLE SPLIT/MERGE PARTITION(S) commands
*/
typedef struct PartitionCmd
{
NodeTag type;
- RangeVar *name; /* name of partition to attach/detach/merge */
- PartitionBoundSpec *bound; /* FOR VALUES, if attaching */
- List *partlist; /* list of partitions to be merged, used in
- * ALTER TABLE MERGE PARTITIONS */
+
+ /* name of partition to attach/detach/merge/split */
+ RangeVar *name;
+
+ /* FOR VALUES, if attaching */
+ PartitionBoundSpec *bound;
+
+ /*
+ * list of partitions to be split/merged, used in ALTER TABLE MERGE
+ * PARTITIONS and ALTER TABLE SPLIT PARTITIONS. For merge partitions,
+ * partlist is a list of RangeVar; For split partition, it is a list of
+ * SinglePartitionSpec.
+ */
+ List *partlist;
+
bool concurrent;
} PartitionCmd;
@@ -2479,6 +2502,7 @@ typedef enum AlterTableType
AT_AttachPartition, /* ATTACH PARTITION */
AT_DetachPartition, /* DETACH PARTITION */
AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */
+ AT_SplitPartition, /* SPLIT PARTITION */
AT_MergePartitions, /* MERGE PARTITIONS */
AT_AddIdentity, /* ADD IDENTITY */
AT_SetIdentity, /* SET identity column options */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index d4cda29c2a2..9fde58f541c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -424,6 +424,7 @@ PG_KEYWORD("smallint", SMALLINT, COL_NAME_KEYWORD, BARE_LABEL)
PG_KEYWORD("snapshot", SNAPSHOT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("some", SOME, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("source", SOURCE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("split", SPLIT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("sql", SQL_P, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("stable", STABLE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("standalone", STANDALONE_P, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h
index 25c311ff9bd..e57c5c20496 100644
--- a/src/include/partitioning/partbounds.h
+++ b/src/include/partitioning/partbounds.h
@@ -143,6 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc,
extern int partition_hash_bsearch(PartitionBoundInfo boundinfo,
int modulus, int remainder);
+extern void check_partitions_for_split(Relation parent,
+ Oid splitPartOid,
+ List *partlist,
+ ParseState *pstate);
extern void calculate_partition_bound_for_merge(Relation parent,
List *partNames,
List *partOids,
diff --git a/src/test/isolation/expected/partition-split.out b/src/test/isolation/expected/partition-split.out
new file mode 100644
index 00000000000..02a5bb4f1f5
--- /dev/null
+++ b/src/test/isolation/expected/partition-split.out
@@ -0,0 +1,230 @@
+Parsed test spec with 2 sessions
+
+starting permutation: s1b s1splt s2b s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2brr s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2bs s2i s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2b s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2brr s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1brr s1splt s2bs s2i s1c s2c s2s
+step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2b s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2brr s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1bs s1splt s2bs s2i s1c s2c s2s
+step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE;
+step s2i: INSERT INTO tpart VALUES (1, 'text01'); <waiting ...>
+step s1c: COMMIT;
+step s2i: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 1|text01
+tpart_00_10 | 5|text05
+tpart_15_20 |15|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(5 rows)
+
+
+starting permutation: s1b s1splt s2b s2u s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u: UPDATE tpart SET i = 16 where i = 5; <waiting ...>
+step s1c: COMMIT;
+step s2u: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_15_20 |15|text15
+tpart_15_20 |16|text05
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
+
+starting permutation: s1b s1splt s2b s2u2 s1c s2c s2s
+step s1b: BEGIN;
+step s1splt: ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (20));
+step s2b: BEGIN;
+step s2u2: UPDATE tpart SET i = 11 where i = 15; <waiting ...>
+step s1c: COMMIT;
+step s2u2: <... completed>
+step s2c: COMMIT;
+step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i;
+tableoid | i|t
+-------------+--+------
+tpart_00_10 | 5|text05
+tpart_10_15 |11|text15
+tpart_20_30 |25|text25
+tpart_default|35|text35
+(4 rows)
+
diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule
index db42c535ba6..f2e067b1fbc 100644
--- a/src/test/isolation/isolation_schedule
+++ b/src/test/isolation/isolation_schedule
@@ -110,6 +110,7 @@ test: partition-key-update-2
test: partition-key-update-3
test: partition-key-update-4
test: partition-merge
+test: partition-split
test: plpgsql-toast
test: cluster-conflict
test: cluster-conflict-partition
diff --git a/src/test/isolation/specs/partition-split.spec b/src/test/isolation/specs/partition-split.spec
new file mode 100644
index 00000000000..af954be5dc0
--- /dev/null
+++ b/src/test/isolation/specs/partition-split.spec
@@ -0,0 +1,62 @@
+# Verify that SPLIT 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 s1splt { ALTER TABLE tpart SPLIT PARTITION tpart_10_20 INTO
+ (PARTITION tpart_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tpart_15_20 FOR VALUES FROM (15) TO (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 s2c { COMMIT; }
+step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; }
+step s2u { UPDATE tpart SET i = 16 where i = 5; }
+step s2u2 { UPDATE tpart SET i = 11 where i = 15; }
+
+
+# s1 starts SPLIT PARTITION then s2 trying to insert row and
+# waits until s1 finished SPLIT operation.
+
+permutation s1b s1splt s2b s2i s1c s2c s2s
+permutation s1b s1splt s2brr s2i s1c s2c s2s
+permutation s1b s1splt s2bs s2i s1c s2c s2s
+
+permutation s1brr s1splt s2b s2i s1c s2c s2s
+permutation s1brr s1splt s2brr s2i s1c s2c s2s
+permutation s1brr s1splt s2bs s2i s1c s2c s2s
+
+permutation s1bs s1splt s2b s2i s1c s2c s2s
+permutation s1bs s1splt s2brr s2i s1c s2c s2s
+permutation s1bs s1splt s2bs s2i s1c s2c s2s
+
+# Tuple routing between partitions.
+permutation s1b s1splt s2b s2u s1c s2c s2s
+
+# Tuple routing inside splitting partition.
+permutation s1b s1splt s2b s2u2 s1c s2c s2s
diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out
index 6b5b40905e7..3a2f576f3b6 100644
--- a/src/test/modules/test_ddl_deparse/expected/alter_table.out
+++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out
@@ -118,6 +118,11 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type MERGE PARTITIONS desc <NULL>
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+NOTICE: DDL test: type alter table, tag ALTER TABLE
+NOTICE: subcommand: type SPLIT PARTITION desc <NULL>
ALTER TABLE part ADD PRIMARY KEY (a);
NOTICE: DDL test: type alter table, tag ALTER TABLE
NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part
diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
index a0549ef8247..0980097048e 100644
--- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql
+++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql
@@ -63,6 +63,10 @@ DROP TABLE part2;
CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200);
ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1;
+ALTER TABLE part SPLIT PARTITION part1 INTO
+ (PARTITION part1 FOR VALUES FROM (1) to (100),
+ PARTITION part2 FOR VALUES FROM (100) to (200));
+
ALTER TABLE part ADD PRIMARY KEY (a);
CREATE TABLE tbl (
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 7de5ddb8785..17d72e412ff 100644
--- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
+++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c
@@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS)
case AT_DetachPartitionFinalize:
strtype = "DETACH PARTITION ... FINALIZE";
break;
+ case AT_SplitPartition:
+ strtype = "SPLIT PARTITION";
+ break;
case AT_MergePartitions:
strtype = "MERGE PARTITIONS";
break;
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
new file mode 100644
index 00000000000..e68baf71daf
--- /dev/null
+++ b/src/test/regress/expected/partition_split.out
@@ -0,0 +1,1592 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+--
+-- BY RANGE partitioning
+--
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_xxx" does not exist
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: relation "sales_jan2022" already exists
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: invalid bound specification for a range partition
+LINE 2: (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '202...
+ ^
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: empty range bound specified for partition "sales_mar2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+DETAIL: Specified lower bound ('03-01-2022') is greater than or equal to upper bound ('02-01-2022').
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+ERROR: list of new partitions should contain at least two partitions
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb_mar_apr2022" is already used
+LINE 3: PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO...
+ ^
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: partition with name "sales_feb2022" is already used
+LINE 3: PARTITION partition_split_schema.sales_feb2022 FOR VALUES...
+ ^
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+DETAIL: This operation is not supported for tables.
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+LINE 3: PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_feb2022"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+LINE 2: (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+----------------+---------+-----------+----------+---------+---------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ partition_split_schema2.sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022')
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+LINE 4: ... sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-0...
+ ^
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+DROP TABLE sales_range;
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+ Partitioned table "partition_split_schema.sales_range"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+------------------+-----------------------+-----------+----------+---------+----------+--------------+-------------
+ salesperson_id | integer | | | | plain | |
+ salesperson_name | character varying(30) | | | | extended | |
+ sales_amount | integer | | | | plain | |
+ sales_date | date | | | | plain | |
+Partition key: RANGE (sales_date)
+Partitions: partition_split_schema2.sales_mar2022 FOR VALUES FROM ('03-01-2022') TO ('04-01-2022'),
+ sales_apr2022 FOR VALUES FROM ('04-01-2022') TO ('05-01-2022'),
+ sales_feb2022 FOR VALUES FROM ('02-01-2022') TO ('03-01-2022'),
+ sales_jan2022 FOR VALUES FROM ('01-01-2022') TO ('02-01-2022'),
+ sales_others DEFAULT
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------------------------+----------------+------------------+--------------+------------
+ partition_split_schema2.sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ partition_split_schema2.sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ partition_split_schema2.sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+-------------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(9 rows)
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+ tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department
+---------------+------------------+------------+-------------+-----------+------------+------------------
+ sales_dec2021 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department
+ sales_dec2021 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department
+ sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department
+ sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department
+ sales_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department
+ sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department
+ sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department
+ sales_jan2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department
+ sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department
+ sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department
+ sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department
+(11 rows)
+
+DROP TABLE sales_date CASCADE;
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT * FROM sales_others;
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 3 | Ford | 2000 | 04-30-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 5 | Deev | 250 | 04-07-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 7 | Li | 175 | 03-08-2022
+ 8 | Ericsson | 185 | 02-23-2022
+ 9 | Muller | 250 | 03-11-2022
+ 11 | Trump | 380 | 04-06-2022
+ 12 | Plato | 350 | 03-19-2022
+ 14 | Smith | 510 | 05-04-2022
+(11 rows)
+
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+--------------+-----------------------------+------------+----------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_others | sales_others_sales_date_idx | | CREATE INDEX sales_others_sales_date_idx ON partition_split_schema.sales_others USING btree (sales_date)
+(1 row)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_feb2022_sales_date_idx on sales_feb2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 2 | Smirnoff | 500 | 02-10-2022
+ 6 | Poirot | 150 | 02-11-2022
+ 8 | Ericsson | 185 | 02-23-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_mar2022_sales_date_idx on sales_mar2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 7 | Li | 175 | 03-08-2022
+ 9 | Muller | 250 | 03-11-2022
+ 12 | Plato | 350 | 03-19-2022
+(3 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ QUERY PLAN
+----------------------------------------------------------------
+ Index Scan using sales_apr2022_sales_date_idx on sales_apr2022
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 11 | Trump | 380 | 04-06-2022
+ 5 | Deev | 250 | 04-07-2022
+ 4 | Ivanov | 750 | 04-13-2022
+ 3 | Ford | 2000 | 04-30-2022
+(4 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+ QUERY PLAN
+---------------------------------------------------------------
+ Index Scan using sales_others_sales_date_idx1 on sales_others
+ Index Cond: (sales_date > '01-01-2022'::date)
+(2 rows)
+
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+ salesperson_id | salesperson_name | sales_amount | sales_date
+----------------+------------------+--------------+------------
+ 14 | Smith | 510 | 05-04-2022
+(1 row)
+
+RESET enable_seqscan;
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+ schemaname | tablename | indexname | tablespace | indexdef
+------------------------+---------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------
+ partition_split_schema | sales_apr2022 | sales_apr2022_sales_date_idx | | CREATE INDEX sales_apr2022_sales_date_idx ON partition_split_schema.sales_apr2022 USING btree (sales_date)
+ partition_split_schema | sales_feb2022 | sales_feb2022_sales_date_idx | | CREATE INDEX sales_feb2022_sales_date_idx ON partition_split_schema.sales_feb2022 USING btree (sales_date)
+ partition_split_schema | sales_mar2022 | sales_mar2022_sales_date_idx | | CREATE INDEX sales_mar2022_sales_date_idx ON partition_split_schema.sales_mar2022 USING btree (sales_date)
+ partition_split_schema | sales_others | sales_others_sales_date_idx1 | | CREATE INDEX sales_others_sales_date_idx1 ON partition_split_schema.sales_others USING btree (sales_date)
+(4 rows)
+
+DROP TABLE sales_range CASCADE;
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+LINE 4: PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO...
+ ^
+DETAIL: lower bound of partition "sales_feb2022" is not equal to the upper bound of partition "sales_error"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+LINE 3: PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO (...
+ ^
+DETAIL: lower bound of partition "sales_error" is not equal to the upper bound of partition "sales_dec2021"
+HINT: ALTER TABLE ... SPLIT PARTITION requires the partition bounds to be adjacent.
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+ERROR: can not split DEFAULT partition "sales_others"
+LINE 2: (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO...
+ ^
+HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+DROP TABLE sales_range;
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+ pg_get_constraintdef | conname | conkey
+---------------------------------------------------------------------+---------------------------------+--------
+ CHECK ((sales_amount > 1)) | sales_range_sales_amount_check | {2}
+ FOREIGN KEY (salesperson_id) REFERENCES salespeople(salesperson_id) | sales_range_salesperson_id_fkey | {1}
+(2 rows)
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+DETAIL: Failing row contains (1, 0, 03-11-2022).
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(-1) is not present in table "salespeople".
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_40 | 10 | May
+ salespeople10_40 | 19 | Ivanov
+ salespeople10_40 | 20 | Smirnoff
+ salespeople10_40 | 30 | Ford
+(5 rows)
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+DETAIL: Key (salesperson_id)=(40) is not present in table "salespeople".
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+----------------+----------------+------------------
+ salespeople1_2 | 1 | Poirot
+ salespeople2_3 | 2 | Ivanov
+ salespeople3_4 | 3 | May
+ salespeople4_5 | 4 | Ford
+(4 rows)
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+ attrelid | attname | attidentity | attgenerated
+----------------+------------------+-------------+--------------
+ salespeople | salesperson_id | a |
+ salespeople | salesperson_name | |
+ salespeople1_2 | salesperson_id | a |
+ salespeople1_2 | salesperson_name | |
+ salespeople2_3 | salesperson_id | a |
+ salespeople2_3 | salesperson_name | |
+ salespeople3_4 | salesperson_id | a |
+ salespeople3_4 | salesperson_name | |
+ salespeople4_5 | salesperson_id | a |
+ salespeople4_5 | salesperson_name | |
+(10 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name
+------------------+----------------+------------------
+ salespeople01_10 | 1 | Poirot
+ salespeople10_20 | 10 | May
+ salespeople10_20 | 19 | Ivanov
+ salespeople20_30 | 20 | Smirnoff
+ salespeople30_40 | 30 | Ford
+(5 rows)
+
+DROP TABLE salespeople CASCADE;
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr_all | 3 | Ford | 2000 | 04-30-2022
+ sales_apr_all | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr_all | 5 | Deev | 250 | 04-07-2022
+ sales_apr_all | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------------+----------------+------------------+--------------+------------
+ sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022
+ sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022 | 7 | Li | 175 | 03-08-2022
+ sales_mar2022 | 9 | Muller | 250 | 03-11-2022
+ sales_mar2022 | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- BY LIST partitioning
+--
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+LINE 3: ... FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'...
+ ^
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+LINE 2: (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York',...
+ ^
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+LINE 2: ...s_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ ^
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+LINE 2: ...st FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne...
+ ^
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+LINE 5: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+ERROR: new partition "x" would overlap with another new partition "x1"
+LINE 2: (PARTITION x FOR VALUES IN ('0'),
+ ^
+DROP TABLE t;
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+ERROR: DEFAULT partition should be one
+LINE 6: PARTITION sales_others2 DEFAULT);
+ ^
+DROP TABLE sales_list;
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+---------------+----------------+------------------+----------------+--------------+------------
+ sales_central | 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ sales_central | 6 | Poirot | Berlin | 1000 | 03-01-2022
+ sales_central | 12 | Smith | Kyiv | 350 | 03-10-2022
+ sales_central | 13 | Gandi | Warsaw | 150 | 03-08-2022
+ sales_east | 1 | Trump | Bejing | 1000 | 03-01-2022
+ sales_east | 8 | Li | Vladivostok | 1150 | 03-09-2022
+ sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022
+ sales_nord | 7 | May | Oslo | 1200 | 03-06-2022
+ sales_nord | 9 | May | Oslo | 1200 | 03-11-2022
+ sales_nord | 10 | Halder | Helsinki | 800 | 03-02-2022
+ sales_west | 2 | Smirnoff | New York | 500 | 03-03-2022
+ sales_west | 5 | Deev | Lisbon | 250 | 03-07-2022
+ sales_west | 11 | Muller | Madrid | 650 | 03-05-2022
+ sales_west | 14 | Plato | Lisbon | 950 | 03-05-2022
+(14 rows)
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+-----------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Index Scan using sales_central_sales_state_idx on sales_central sales_list
+ Index Cond: ((sales_state)::text = 'Warsaw'::text)
+(2 rows)
+
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+ 13 | Gandi | Warsaw | 150 | 03-08-2022
+(2 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Append
+ -> Index Scan using sales_east_salesperson_name_idx on sales_east sales_list_1
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_central_salesperson_name_idx on sales_central sales_list_2
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_nord sales_list_3
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_nord_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Index Scan using sales_west_salesperson_name_idx on sales_west sales_list_4
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Heap Scan on sales_others sales_list_5
+ Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text)
+ -> Bitmap Index Scan on sales_others_salesperson_name_idx
+ Index Cond: ((salesperson_name)::text = 'Ivanov'::text)
+(15 rows)
+
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+ salesperson_id | salesperson_name | sales_state | sales_amount | sales_date
+----------------+------------------+-------------+--------------+------------
+ 4 | Ivanov | Warsaw | 750 | 03-04-2022
+(1 row)
+
+RESET enable_seqscan;
+DROP TABLE sales_list;
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+-----------------------+----------------+------------------+--------------+------------
+ sales_apr2022_1decade | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022_1decade | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022_1decade | 2 | Smirnoff | 500 | 02-09-2022
+ sales_feb2022_1decade | 6 | Poirot | 150 | 02-07-2022
+ sales_jan2022_1decade | 13 | Gandi | 377 | 01-09-2022
+ sales_mar2022_1decade | 7 | Li | 175 | 03-08-2022
+ sales_others | 1 | May | 1000 | 01-31-2022
+ sales_others | 3 | Ford | 2000 | 04-30-2022
+ sales_others | 4 | Ivanov | 750 | 04-13-2022
+ sales_others | 8 | Ericsson | 185 | 02-23-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 10 | Halder | 350 | 01-28-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+(13 rows)
+
+DROP TABLE sales_range;
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+ tableoid | salesperson_id | salesperson_name | sales_amount | sales_date
+---------------+----------------+------------------+--------------+------------
+ sales_apr2022 | 3 | Ford | 2000 | 04-30-2022
+ sales_apr2022 | 4 | Ivanov | 750 | 04-13-2022
+ sales_apr2022 | 5 | Deev | 250 | 04-07-2022
+ sales_apr2022 | 11 | Trump | 380 | 04-06-2022
+ sales_feb2022 | 2 | Smirnoff | 500 | 02-10-2022
+ sales_feb2022 | 6 | Poirot | 150 | 02-11-2022
+ sales_feb2022 | 8 | Ericsson | 185 | 02-23-2022
+ sales_jan2022 | 1 | May | 1000 | 01-31-2022
+ sales_jan2022 | 10 | Halder | 350 | 01-28-2022
+ sales_jan2022 | 13 | Gandi | 377 | 01-09-2022
+ sales_others | 7 | Li | 175 | 03-08-2022
+ sales_others | 9 | Muller | 250 | 03-11-2022
+ sales_others | 12 | Plato | 350 | 03-19-2022
+ sales_others | 14 | Smith | 510 | 05-04-2022
+(14 rows)
+
+DROP TABLE sales_range;
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+ERROR: relation "t1pa" is not a partition of relation "t2"
+HINT: ALTER TABLE ... SPLIT PARTITION can only split partitions don't have sub-partitions
+DROP TABLE t2;
+DROP TABLE t1;
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_2 | FOR VALUES FROM (0) TO (2) | t
+(1 row)
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+ oid | pg_get_expr | relpersistence
+--------+----------------------------+----------------
+ tp_0_1 | FOR VALUES FROM (0) TO (1) | t
+ tp_1_2 | FOR VALUES FROM (1) TO (2) | t
+(2 rows)
+
+DROP TABLE t;
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+ tablename | tablespace
+-----------+------------------
+ t | regress_tblspace
+ tp_0_1 | regress_tblspace
+ tp_1_2 | regress_tblspace
+(3 rows)
+
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+ tablename | indexname | tablespace
+-----------+-------------+------------------
+ t | t_pkey | regress_tblspace
+ tp_0_1 | tp_0_1_pkey | regress_tblspace
+ tp_1_2 | tp_1_2_pkey | regress_tblspace
+(3 rows)
+
+DROP TABLE t;
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+ relname | amname
+---------+----------------------
+ t | partition_split_heap
+ tp_0_1 | partition_split_heap
+ tp_1_2 | partition_split_heap
+(3 rows)
+
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+ Partitioned table "partition_split_schema.t_bigint"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition key: RANGE (b)
+Partitions: t_bigint_default DEFAULT
+
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+No partition constraint
+
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+ Table "partition_split_schema.t_bigint_default"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint DEFAULT
+Partition constraint: (NOT ((b IS NOT NULL) AND ((b >= '0'::bigint) AND (b < '10'::bigint))))
+
+\d+ t_bigint_01_10
+ Table "partition_split_schema.t_bigint_01_10"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+---------------------------------------+---------+--------------+-------------
+ b | bigint | | | | plain | |
+ i | integer | | | 3 + 10 | plain | |
+ j | integer | | | 101 | plain | |
+ k | integer | | | generated always as ((b + 10)) stored | plain | |
+Partition of: t_bigint FOR VALUES FROM ('0') TO ('10')
+Partition constraint: ((b IS NOT NULL) AND (b >= '0'::bigint) AND (b < '10'::bigint))
+
+DROP TABLE t_bigint;
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table t
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+ERROR: must be owner of table tp_0_2
+RESET SESSION AUTHORIZATION;
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+DROP TABLE t;
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_2 | table | regress_partition_split_alice
+(1 row)
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_0_1 | table | regress_partition_split_alice
+(1 row)
+
+\dt tp_1_2
+ List of tables
+ Schema | Name | Type | Owner
+------------------------+--------+-------+-------------------------------
+ partition_split_schema | tp_1_2 | table | regress_partition_split_alice
+(1 row)
+
+DROP TABLE t;
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+RESET SESSION AUTHORIZATION;
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+NOTICE: you are running me as regress_partition_split_alice
+NOTICE: you are running me as regress_partition_split_alice
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+ERROR: partition of hash-partitioned table cannot be split
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+ERROR: list of new partitions should contain at least two partitions
+DROP TABLE t;
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+-------------
+ i | integer | | not null | | plain | | tp_x.i
+ t | text | | | 'default_tp_x'::text | main | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('02-02-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (0) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Statistics objects:
+ "partition_split_schema.tp_x_stat" (dependencies) ON i, b FROM tp_x
+Not-null constraints:
+ "tp_x_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+ tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_x')
+
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+ Table "partition_split_schema.tp_x"
+ Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
+--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+-------------
+ i | integer | | not null | | plain | |
+ t | text | | | 'default_t'::text | extended | |
+ b | bigint | | not null | | plain | |
+ d | date | | | generated always as ('01-01-2022'::date) stored | plain | |
+Partition of: t FOR VALUES FROM (1) TO (2)
+Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 1) AND (abs(i) < 2))
+Check constraints:
+ "t_b_check" CHECK (b > 0)
+ "t_b_check1" CHECK (b > 0) NOT ENFORCED
+ "t_b_check2" CHECK (b > 0) NOT VALID
+Not-null constraints:
+ "t_i_not_null" NOT NULL "i" (inherited)
+ "t_b_nn" NOT NULL "b" (inherited) NOT VALID
+Triggers:
+ t_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+ tableoid | i | t | b | d
+----------+---+--------------+---+------------
+ tp_0_1 | 0 | default_tp_x | 1 | 01-01-2022
+ tp_x | 1 | default_tp_x | 2 | 01-01-2022
+ tp_x | 1 | default_t | 3 | 01-01-2022
+(3 rows)
+
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 1
+(1 row)
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+ count
+-------
+ 0
+(1 row)
+
+DROP TABLE t;
+RESET search_path;
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 633cf20e0a6..89bde9a2850 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -123,7 +123,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_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
+test: partition_merge partition_split partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate
# event_trigger depends on create_am and cannot run concurrently with
# any test that runs DDL
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
new file mode 100644
index 00000000000..0e79c036ea9
--- /dev/null
+++ b/src/test/regress/sql/partition_split.sql
@@ -0,0 +1,1134 @@
+--
+-- PARTITION_SPLIT
+-- Tests for "ALTER TABLE ... SPLIT PARTITION ..." command
+--
+
+CREATE SCHEMA partition_split_schema;
+CREATE SCHEMA partition_split_schema2;
+SET search_path = partition_split_schema, public;
+
+--
+-- BY RANGE partitioning
+--
+
+--
+-- Test for error codes
+--
+CREATE TABLE sales_range (salesperson_id 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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- ERROR: relation "sales_xxx" does not exist
+ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: relation "sales_jan2022" already exists
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: invalid bound specification for a range partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES IN ('2022-05-01', '2022-06-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: empty range bound specified for partition "sales_mar2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-02-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+--ERROR: list of split partitions should contain at least two items
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-10-01'));
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-01-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb_mar_apr2022" is already used
+-- (We can create partition with the same name as split partition, but can't create two partitions with the same name)
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb_mar_apr2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: partition with name "sales_feb2022" is already used
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: ALTER action SPLIT PARTITION cannot be performed on relation "sales_feb_mar_apr2022"
+-- DETAIL: This operation is not supported for tables.
+ALTER TABLE sales_feb_mar_apr2022 SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+-- ERROR: can not split to partition "sales_mar2022" together with partition "sales_feb2022"
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-02-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Tests for spaces between partitions, them should be executed without DEFAULT partition
+ALTER TABLE sales_range DETACH PARTITION sales_others;
+
+-- ERROR: lower bound of partition "sales_feb2022" is not equal to lower bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-02') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- Check the source partition not in the search path
+SET search_path = partition_split_schema2, public;
+ALTER TABLE partition_split_schema.sales_range
+SPLIT PARTITION partition_split_schema.sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+SET search_path = partition_split_schema, public;
+\d+ sales_range
+
+DROP TABLE sales_range;
+DROP TABLE sales_others;
+
+-- Additional tests for error messages, no default partition
+CREATE TABLE sales_range (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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+-- ERROR: upper bound of partition "sales_apr2022" is not equal to upper bound of split partition "sales_feb_mar_apr2022"
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-06-01'));
+
+DROP TABLE sales_range;
+
+--
+-- Add rows into partitioned table then split partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+DROP TABLE sales_range CASCADE;
+
+--
+-- Add split partition, then add rows into partitioned table
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+-- Split partition, also check schema qualification of new partitions
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION partition_split_schema.sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION partition_split_schema2.sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+\d+ sales_range
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test for:
+-- * composite partition key;
+-- * GENERATED column;
+-- * column with DEFAULT value.
+--
+CREATE TABLE sales_date (salesperson_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_dec2021 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1);
+CREATE TABLE sales_jan_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 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(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2021, 12, 7),
+ ('Manager2', 2021, 12, 8),
+ ('Manager3', 2022, 1, 1),
+ ('Manager1', 2022, 2, 4),
+ ('Manager2', 2022, 1, 2),
+ ('Manager3', 2022, 2, 1),
+ ('Manager1', 2022, 3, 3),
+ ('Manager2', 2022, 3, 4),
+ ('Manager3', 2022, 5, 1);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+ALTER TABLE sales_date SPLIT PARTITION sales_jan_feb2022 INTO
+ (PARTITION sales_jan2022 FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1),
+ PARTITION sales_feb2022 FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1));
+
+INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES
+ ('Manager1', 2022, 1, 10),
+ ('Manager2', 2022, 2, 10);
+
+SELECT tableoid::regclass, * FROM sales_date ORDER BY tableoid::regclass::text COLLATE "C", sales_year, sales_month, sales_day;
+
+DROP TABLE sales_date CASCADE;
+
+--
+-- Test: split DEFAULT partition; use an index on partition key; check index after split
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT * FROM sales_others;
+SELECT * FROM pg_indexes WHERE tablename = 'sales_others' and schemaname = 'partition_split_schema' ORDER BY indexname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_others DEFAULT);
+
+-- Use indexscan for testing indexes
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_feb2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_mar2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+SELECT * FROM sales_apr2022 where sales_date > '2022-01-01';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_others where sales_date > '2022-01-01';
+SELECT * FROM sales_others where sales_date > '2022-01-01';
+
+RESET enable_seqscan;
+
+SELECT * FROM pg_indexes
+WHERE tablename in ('sales_feb2022', 'sales_mar2022', 'sales_apr2022', 'sales_others')
+AND schemaname = 'partition_split_schema'
+ORDER BY indexname COLLATE "C";
+
+DROP TABLE sales_range CASCADE;
+
+--
+-- Test: some cases for splitting DEFAULT partition (different bounds)
+--
+CREATE TABLE sales_range (salesperson_id INT, sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- sales_error intersects with sales_dec2021 (lower bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-30') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_feb2022 (upper bound)
+-- ERROR: can not split to partition "sales_feb2022" together with partition "sales_error"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2022-01-01') TO ('2022-02-02'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (inside bound)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-10') TO ('2021-12-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- sales_error intersects with sales_dec2021 (exactly the same bounds)
+-- ERROR: can not split to partition "sales_error" together with partition "sales_dec2021"
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_error FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+-- ERROR: can not split DEFAULT partition "sales_others"
+-- HINT: To split DEFAULT partition one of the new partition msut be DEFAULT
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_jan2022 FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'));
+
+-- no error: bounds of sales_noerror are between sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-10') TO ('2022-01-20'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+CREATE TABLE sales_range (sales_date date) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+-- no error: bounds of sales_noerror are equal to lower and upper bounds of sales_dec2021 and sales_feb2022
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_dec2021 FOR VALUES FROM ('2021-12-01') TO ('2022-01-01'),
+ PARTITION sales_noerror FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+DROP TABLE sales_range;
+
+--
+-- Test: split partition with CHECK and FOREIGN KEY CONSTRAINTs on partitioned table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30));
+INSERT INTO salespeople VALUES (1, 'Poirot');
+
+CREATE TABLE sales_range (
+salesperson_id INT REFERENCES salespeople(salesperson_id),
+sales_amount INT CHECK (sales_amount > 1),
+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_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb_mar_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'),
+ PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'));
+
+-- We should see the same CONSTRAINTs as on sales_feb_mar_apr2022 partition
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_feb2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_mar2022'::regclass::oid ORDER BY conname COLLATE "C";
+SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'sales_apr2022'::regclass::oid ORDER BY conname COLLATE "C";
+
+-- ERROR: new row for relation "sales_mar2022" violates check constraint "sales_range_sales_amount_check"
+INSERT INTO sales_range VALUES (1, 0, '2022-03-11');
+-- ERROR: insert or update on table "sales_mar2022" violates foreign key constraint "sales_range_salesperson_id_fkey"
+INSERT INTO sales_range VALUES (-1, 10, '2022-03-11');
+-- ok
+INSERT INTO sales_range VALUES (1, 10, '2022-03-11');
+
+DROP TABLE sales_range CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition on partitioned table in case of existing FOREIGN KEY reference from another table
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+CREATE TABLE sales (salesperson_id INT REFERENCES salespeople(salesperson_id), sales_amount INT, sales_date DATE);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (19, 'Ivanov'),
+ (20, 'Smirnoff'),
+ (30, 'Ford');
+
+INSERT INTO sales VALUES
+ (1, 100, '2022-03-01'),
+ (1, 110, '2022-03-02'),
+ (10, 150, '2022-03-01'),
+ (10, 90, '2022-03-03'),
+ (19, 200, '2022-03-04'),
+ (20, 50, '2022-03-12'),
+ (20, 170, '2022-03-02'),
+ (30, 30, '2022-03-04');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- ERROR: insert or update on table "sales" violates foreign key constraint "sales_salesperson_id_fkey"
+INSERT INTO sales VALUES (40, 50, '2022-03-04');
+-- ok
+INSERT INTO sales VALUES (30, 50, '2022-03-04');
+
+DROP TABLE sales CASCADE;
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition of partitioned table with triggers
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+CREATE TABLE salespeople10_40 PARTITION OF salespeople FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople 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 salespeople_after_insert_statement_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH STATEMENT
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+CREATE TRIGGER salespeople_after_insert_row_trigger
+ AFTER INSERT
+ ON salespeople
+ FOR EACH ROW
+ EXECUTE PROCEDURE after_insert_row_trigger('salespeople');
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (10, 'May');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople10_40 VALUES (19, 'Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+-- 2 triggers should fire here (row + statement):
+INSERT INTO salespeople VALUES (20, 'Smirnoff');
+-- 1 trigger should fire here (row):
+INSERT INTO salespeople30_40 VALUES (30, 'Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+DROP FUNCTION after_insert_row_trigger();
+
+--
+-- Test: split partition witch identity column
+-- If split partition column is identity column, columns of new partitions are identity columns too.
+--
+CREATE TABLE salespeople(salesperson_id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople1_2 PARTITION OF salespeople FOR VALUES FROM (1) TO (2);
+-- Create new partition with identity column:
+CREATE TABLE salespeople2_5(salesperson_id INT NOT NULL, salesperson_name VARCHAR(30));
+ALTER TABLE salespeople ATTACH PARTITION salespeople2_5 FOR VALUES FROM (2) TO (5);
+
+INSERT INTO salespeople (salesperson_name) VALUES ('Poirot'), ('Ivanov');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople2_5 INTO
+ (PARTITION salespeople2_3 FOR VALUES FROM (2) TO (3),
+ PARTITION salespeople3_4 FOR VALUES FROM (3) TO (4),
+ PARTITION salespeople4_5 FOR VALUES FROM (4) TO (5));
+
+INSERT INTO salespeople (salesperson_name) VALUES ('May'), ('Ford');
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- check new partitions have identity or not after split partition
+SELECT attrelid::regclass, attname, attidentity, attgenerated FROM pg_attribute
+WHERE attnum > 0
+AND attrelid::regclass IN (
+ 'salespeople2_3'::regclass, 'salespeople', 'salespeople2_3',
+ 'salespeople1_2', 'salespeople3_4', 'salespeople4_5')
+ORDER BY attrelid::regclass::text COLLATE "C", attnum;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split partition with deleted columns
+--
+CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id);
+
+CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10);
+-- Create new partition with some deleted columns:
+CREATE TABLE salespeople10_40(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, d2 INT, d3 DATE, salesperson_name VARCHAR(30));
+
+INSERT INTO salespeople10_40 VALUES
+ ('dummy value 1', 19, 100, now(), 'Ivanov'),
+ ('dummy value 2', 20, 101, now(), 'Smirnoff');
+
+ALTER TABLE salespeople10_40 DROP COLUMN d1;
+ALTER TABLE salespeople10_40 DROP COLUMN d2;
+ALTER TABLE salespeople10_40 DROP COLUMN d3;
+
+ALTER TABLE salespeople ATTACH PARTITION salespeople10_40 FOR VALUES FROM (10) TO (40);
+
+INSERT INTO salespeople VALUES
+ (1, 'Poirot'),
+ (10, 'May'),
+ (30, 'Ford');
+
+ALTER TABLE salespeople SPLIT PARTITION salespeople10_40 INTO
+ (PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20),
+ PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30),
+ PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40));
+
+SELECT tableoid::regclass, * FROM salespeople ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE salespeople CASCADE;
+
+--
+-- Test: split sub-partition
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_apr_all PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') 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'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+ALTER TABLE sales_apr2022 SPLIT PARTITION sales_apr_all INTO
+ (PARTITION sales_apr2022_01_10 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_apr2022_10_20 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'),
+ PARTITION sales_apr2022_20_30 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- BY LIST partitioning
+--
+
+--
+-- Test: specific errors for BY LIST partitioning
+--
+CREATE TABLE sales_list (sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+-- ERROR: new partition "sales_east" would overlap with another (not split) partition "sales_nord"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok', 'Helsinki'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" would overlap with another new partition "sales_central"
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Lisbon', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have NULL value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', NULL),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition "sales_west" cannot have this value because split partition "sales_all" does not have
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partition cannot be DEFAULT because DEFAULT partition "sales_others" already exists
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Melbourne'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+-- Test for non-symbolic comparison of values (numeric values '0' and '0.0' are equal).
+CREATE TABLE t (a numeric) PARTITION BY LIST (a);
+CREATE TABLE t1 PARTITION OF t FOR VALUES in ('0', '1');
+-- ERROR: new partition "x" would overlap with another new partition "x1"
+ALTER TABLE t SPLIT PARTITION t1 INTO
+ (PARTITION x FOR VALUES IN ('0'),
+ PARTITION x1 FOR VALUES IN ('0.0', '1'));
+DROP TABLE t;
+
+--
+-- Test: two specific errors for BY LIST partitioning:
+-- * new partitions do not have NULL value, which split partition has.
+-- * new partitions do not have a value that split partition has.
+--
+CREATE TABLE sales_list(sales_state VARCHAR(20)) PARTITION BY LIST (sales_state);
+
+CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok', NULL);
+
+-- ERROR: new partitions combined partition bounds do not contain value (NULL) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+-- ERROR: new partitions combined partition bounds do not contain value ('Kyiv'::character varying(20)) but split partition "sales_all" does
+-- HINT: ALTER TABLE ... SPLIT PARTITION require combined bounds of new partitions must exactly match the bound of the split partition
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', NULL));
+
+-- ERROR DEFAULT partition should be one
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'),
+ PARTITION sales_others DEFAULT,
+ PARTITION sales_others2 DEFAULT);
+
+DROP TABLE sales_list;
+
+--
+-- Test: BY LIST partitioning, SPLIT PARTITION with data
+--
+CREATE TABLE sales_list
+(salesperson_id SERIAL,
+ salesperson_name VARCHAR(30),
+ sales_state VARCHAR(20),
+ sales_amount INT,
+ sales_date DATE)
+PARTITION BY LIST (sales_state);
+
+CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_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 ('Helsinki', 'St. Petersburg', 'Oslo');
+CREATE TABLE sales_all PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Lisbon', 'New York', 'Madrid', 'Bejing', 'Berlin', 'Delhi', 'Kyiv', 'Vladivostok');
+CREATE TABLE sales_others PARTITION OF sales_list DEFAULT;
+
+INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES
+ ('Trump', 'Bejing', 1000, '2022-03-01'),
+ ('Smirnoff', 'New York', 500, '2022-03-03'),
+ ('Ford', 'St. Petersburg', 2000, '2022-03-05'),
+ ('Ivanov', 'Warsaw', 750, '2022-03-04'),
+ ('Deev', 'Lisbon', 250, '2022-03-07'),
+ ('Poirot', 'Berlin', 1000, '2022-03-01'),
+ ('May', 'Oslo', 1200, '2022-03-06'),
+ ('Li', 'Vladivostok', 1150, '2022-03-09'),
+ ('May', 'Oslo', 1200, '2022-03-11'),
+ ('Halder', 'Helsinki', 800, '2022-03-02'),
+ ('Muller', 'Madrid', 650, '2022-03-05'),
+ ('Smith', 'Kyiv', 350, '2022-03-10'),
+ ('Gandi', 'Warsaw', 150, '2022-03-08'),
+ ('Plato', 'Lisbon', 950, '2022-03-05');
+
+ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
+
+SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+-- Use indexscan for testing indexes after splitting partition
+SET enable_seqscan = OFF;
+
+EXPLAIN (COSTS OFF) SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_central WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+SELECT * FROM sales_list WHERE sales_state = 'Warsaw';
+EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov';
+
+RESET enable_seqscan;
+
+DROP TABLE sales_list;
+
+--
+-- Test for:
+-- * split DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09'),
+ (14, 'Smith', 510, '2022-05-04');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_others INTO
+ (PARTITION sales_others DEFAULT,
+ PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'));
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for:
+-- * split non-DEFAULT partition to partitions with spaces between bounds;
+-- * random order of partitions in SPLIT PARTITION command.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date);
+CREATE TABLE sales_all PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-09'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-07'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_mar2022_1decade FOR VALUES FROM ('2022-03-01') TO ('2022-03-10'),
+ PARTITION sales_jan2022_1decade FOR VALUES FROM ('2022-01-01') TO ('2022-01-10'),
+ PARTITION sales_feb2022_1decade FOR VALUES FROM ('2022-02-01') TO ('2022-02-10'),
+ PARTITION sales_apr2022_1decade FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'),
+ PARTITION sales_others DEFAULT);
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Test for split non-DEFAULT partition to DEFAULT partition + partitions
+-- with spaces between bounds.
+--
+CREATE TABLE sales_range (salesperson_id INT, salesperson_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_all PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
+
+INSERT INTO sales_range VALUES
+ (1, 'May', 1000, '2022-01-31'),
+ (2, 'Smirnoff', 500, '2022-02-10'),
+ (3, 'Ford', 2000, '2022-04-30'),
+ (4, 'Ivanov', 750, '2022-04-13'),
+ (5, 'Deev', 250, '2022-04-07'),
+ (6, 'Poirot', 150, '2022-02-11'),
+ (7, 'Li', 175, '2022-03-08'),
+ (8, 'Ericsson', 185, '2022-02-23'),
+ (9, 'Muller', 250, '2022-03-11'),
+ (10, 'Halder', 350, '2022-01-28'),
+ (11, 'Trump', 380, '2022-04-06'),
+ (12, 'Plato', 350, '2022-03-19'),
+ (13, 'Gandi', 377, '2022-01-09');
+
+ALTER TABLE sales_range SPLIT PARTITION sales_all INTO
+ (PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'),
+ PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_others DEFAULT);
+
+INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04');
+
+SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id;
+
+DROP TABLE sales_range;
+
+--
+-- Try to SPLIT partition of another table.
+--
+CREATE TABLE t1(i int, t text) PARTITION BY LIST (t);
+CREATE TABLE t1pa PARTITION OF t1 FOR VALUES IN ('A');
+CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t);
+
+-- ERROR: relation "t1pa" is not a partition of relation "t2"
+ALTER TABLE t2 SPLIT PARTITION t1pa INTO
+ (PARTITION t2a FOR VALUES FROM ('A') TO ('B'),
+ PARTITION t2b FOR VALUES FROM ('B') TO ('C'));
+
+DROP TABLE t2;
+DROP TABLE t1;
+
+--
+-- Try to SPLIT partition of temporary table.
+--
+CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TEMP TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+-- ERROR: cannot create a permanent relation as partition of temporary relation "t"
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION pg_temp.tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Partitions should be temporary.
+SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence
+ FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+ WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass
+ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text COLLATE "C";
+
+DROP TABLE t;
+
+-- Check the new partitions inherit parent's tablespace
+CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace)
+ PARTITION BY RANGE (i) TABLESPACE regress_tblspace;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT tablename, tablespace FROM pg_tables
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", tablespace COLLATE "C";
+SELECT tablename, indexname, tablespace FROM pg_indexes
+ WHERE tablename IN ('t', 'tp_0_1', 'tp_1_2') AND schemaname = 'partition_split_schema'
+ ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C";
+DROP TABLE t;
+
+-- Check new partitions inherits parent's table access method
+CREATE ACCESS METHOD partition_split_heap TYPE TABLE HANDLER heap_tableam_handler;
+CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partition_split_heap;
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+SELECT c.relname, a.amname
+FROM pg_class c JOIN pg_am a ON c.relam = a.oid
+WHERE c.oid IN ('t'::regclass, 'tp_0_1'::regclass, 'tp_1_2'::regclass)
+ORDER BY c.relname COLLATE "C";
+DROP TABLE t;
+DROP ACCESS METHOD partition_split_heap;
+
+-- Split partition of a temporary table when one of the partitions after
+-- split has the same name as the partition being split
+CREATE TEMP TABLE t (a int) PARTITION BY RANGE (a);
+CREATE TEMP TABLE tp_0 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t SPLIT PARTITION tp_0 INTO
+ (PARTITION pg_temp.tp_0 FOR VALUES FROM (0) TO (1),
+ PARTITION pg_temp.tp_1 FOR VALUES FROM (1) TO (2));
+DROP TABLE t;
+
+-- Check defaults and constraints of new partitions
+CREATE TABLE t_bigint (
+ b bigint,
+ i int DEFAULT (3+10),
+ j int DEFAULT 101,
+ k int GENERATED ALWAYS AS (b+10) STORED
+)
+PARTITION BY RANGE (b);
+CREATE TABLE t_bigint_default PARTITION OF t_bigint DEFAULT;
+-- Show defaults/constraints before SPLIT PARTITION
+\d+ t_bigint
+\d+ t_bigint_default
+ALTER TABLE t_bigint SPLIT PARTITION t_bigint_default INTO
+ (PARTITION t_bigint_01_10 FOR VALUES FROM (0) TO (10),
+ PARTITION t_bigint_default DEFAULT);
+-- Show defaults/constraints after SPLIT PARTITION
+\d+ t_bigint_default
+\d+ t_bigint_01_10
+DROP TABLE t_bigint;
+
+-- Test permission checks. The user needs to own the parent table and the
+-- the partition to split to do the split.
+CREATE ROLE regress_partition_split_alice;
+CREATE ROLE regress_partition_split_bob;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_alice;
+GRANT ALL ON SCHEMA partition_split_schema TO regress_partition_split_bob;
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --error
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE tp_0_2 OWNER TO regress_partition_split_bob;
+SET SESSION AUTHORIZATION regress_partition_split_bob;
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2)); --ok
+RESET SESSION AUTHORIZATION;
+
+DROP TABLE t;
+
+-- Test: owner of new partitions should be the same as owner of split partition
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE tp_0_2(i int);
+RESET SESSION AUTHORIZATION;
+
+ALTER TABLE t ATTACH PARTITION tp_0_2 FOR VALUES FROM (0) TO (2);
+
+-- Owner is 'regress_partition_split_alice':
+\dt tp_0_2
+
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Owner should be 'regress_partition_split_alice':
+\dt tp_0_1
+\dt tp_1_2
+
+DROP TABLE t;
+
+-- Test: index of new partitions should be created with same owner as split
+-- partition
+SET SESSION AUTHORIZATION regress_partition_split_alice;
+CREATE TABLE t (i int) PARTITION BY RANGE (i);
+CREATE TABLE tp_10_20 PARTITION OF t FOR VALUES FROM (10) TO (20);
+INSERT INTO t VALUES (11), (16);
+CREATE OR REPLACE FUNCTION run_me(integer) RETURNS integer AS $$
+BEGIN
+ RAISE NOTICE 'you are running me as %', CURRENT_USER;
+ RETURN $1;
+END
+$$ LANGUAGE PLPGSQL IMMUTABLE;
+
+-- Owner is 'regress_partition_split_alice':
+CREATE INDEX ON t (run_me(i));
+RESET SESSION AUTHORIZATION;
+
+-- Owner should be 'regress_partition_split_alice':
+ALTER TABLE t SPLIT PARTITION tp_10_20 INTO
+ (PARTITION tp_10_15 FOR VALUES FROM (10) TO (15),
+ PARTITION tp_15_20 FOR VALUES FROM (15) TO (20));
+
+DROP TABLE t;
+DROP FUNCTION run_me(integer);
+
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_alice;
+REVOKE ALL ON SCHEMA partition_split_schema FROM regress_partition_split_bob;
+DROP ROLE regress_partition_split_alice;
+DROP ROLE regress_partition_split_bob;
+
+-- Test for hash partitioned table
+CREATE TABLE t (i int) PARTITION BY HASH(i);
+CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1);
+
+-- ERROR: partition of hash-partitioned table cannot be split
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0),
+ PARTITION tp1_2 FOR VALUES WITH (MODULUS 4, REMAINDER 2));
+
+-- ERROR: list of new partitions should contain at least two partitions
+ALTER TABLE t SPLIT PARTITION tp1 INTO
+ (PARTITION tp1_1 FOR VALUES WITH (MODULUS 4, REMAINDER 0));
+
+DROP TABLE t;
+
+
+-- Test for split partition properties:
+-- * STATISTICS is empty
+-- * COMMENT is empty
+-- * DEFAULTS are the same as DEFAULTS for partitioned table
+-- * STORAGE is the same as STORAGE for partitioned table
+-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table
+-- * TRIGGERS are the same as TRIGGERS for partitioned table
+
+CREATE TABLE t
+(i int NOT NULL,
+ t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i));
+COMMENT ON COLUMN t.i IS 't1.i';
+
+CREATE TABLE tp_x
+(i int NOT NULL,
+ t text STORAGE MAIN DEFAULT 'default_tp_x',
+ b bigint,
+ d date GENERATED ALWAYS as ('2022-02-02') STORED);
+ALTER TABLE t ATTACH PARTITION tp_x FOR VALUES FROM (0) TO (2);
+COMMENT ON COLUMN tp_x.i IS 'tp_x.i';
+
+CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t;
+CREATE STATISTICS tp_x_stat (DEPENDENCIES) on i, b from tp_x;
+
+ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0);
+ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED;
+ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID;
+ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID;
+
+INSERT INTO tp_x(i, t, b) VALUES(0, DEFAULT, 1);
+INSERT INTO tp_x(i, t, b) VALUES(1, DEFAULT, 2);
+
+CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS
+$BODY$
+BEGIN
+ RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN new;
+END;
+$BODY$;
+
+CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('t');
+CREATE TRIGGER tp_x_before_insert_row_trigger BEFORE INSERT ON tp_x FOR EACH ROW
+ EXECUTE PROCEDURE trigger_function('tp_x');
+
+\d+ tp_x
+ALTER TABLE t SPLIT PARTITION tp_x INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_x FOR VALUES FROM (1) TO (2));
+\d+ tp_x
+
+INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3);
+SELECT tableoid::regclass, * FROM t ORDER BY tableoid::regclass::text COLLATE "C", b;
+DROP TABLE t;
+DROP FUNCTION trigger_function();
+
+
+-- Test for recomputation of stored generated columns.
+CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i);
+CREATE TABLE tp_0_2 PARTITION OF t FOR VALUES FROM (0) TO (2);
+ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789);
+INSERT INTO t VALUES (0), (1);
+
+-- Should be 1 because partition identifier for row with i=0 is the same as
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+-- "tab_id" column (stored generated column) with "tableoid" attribute requires
+-- recomputation here.
+ALTER TABLE t SPLIT PARTITION tp_0_2 INTO
+ (PARTITION tp_0_1 FOR VALUES FROM (0) TO (1),
+ PARTITION tp_1_2 FOR VALUES FROM (1) TO (2));
+
+-- Should be 0 because partition identifier for row with i=0 is different from
+-- partition identifier for row with i=1.
+SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1);
+
+DROP TABLE t;
+
+
+RESET search_path;
+
+--
+DROP SCHEMA partition_split_schema;
+DROP SCHEMA partition_split_schema2;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9dd65b10254..161cbec46af 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -2800,6 +2800,7 @@ SimpleStats
SimpleStringList
SimpleStringListCell
SingleBoundSortItem
+SinglePartitionSpec
Size
SkipPages
SkipSupport
@@ -2868,6 +2869,7 @@ SpecialJoinInfo
SpinDelayStatus
SplitInterval
SplitLR
+SplitPartitionContext
SplitPageLayout
SplitPoint
SplitTextOutputData
--
2.39.5 (Apple Git-154)
Hi everyone,
I just noticed two relatively large commits. I recall that not long ago we started attempting to adopt `palloc_object` and `palloc_array` in many places,
yet in these two commits, some sections have used the new approach while others have not.
Perhaps we could standardize the coding style for consistency.
src/backend/commands/tablecmds.c
src/backend/partitioning/partbounds.c
Regards,
Man Zeng
Hi Man,
On Sun, Dec 14, 2025 at 2:51 PM zengman <zengman@halodbtech.com> wrote:
I just noticed two relatively large commits. I recall that not long ago we started attempting to adopt `palloc_object` and `palloc_array` in many places,
yet in these two commits, some sections have used the new approach while others have not.
Perhaps we could standardize the coding style for consistency.src/backend/commands/tablecmds.c
src/backend/partitioning/partbounds.c
Thank you for noticing this. I'm going to prepare patches to adopt
`palloc_object` and `palloc_array` in my recent commits right away.
------
Regards,
Alexander Korotkov
Supabase
Hi Man,
On Sun, Dec 14, 2025 at 2:51 PM zengman <zengman@halodbtech.com> wrote:
I just noticed two relatively large commits. I recall that not long ago we started attempting to adopt `palloc_object` and `palloc_array` in many places,
yet in these two commits, some sections have used the new approach while others have not.
Perhaps we could standardize the coding style for consistency.src/backend/commands/tablecmds.c
src/backend/partitioning/partbounds.c
Could you, please, check the attached patch?
------
Regards,
Alexander Korotkov
Supabase
Attachments:
v1-0001-Fix-usage-of-palloc-in-MERGE-SPLIT-PARTITION-s-co.patchapplication/octet-stream; name=v1-0001-Fix-usage-of-palloc-in-MERGE-SPLIT-PARTITION-s-co.patchDownload
From b964df0852b32c046cf2f298bbd0d528be85f48a Mon Sep 17 00:00:00 2001
From: Alexander Korotkov <akorotkov@postgresql.org>
Date: Sun, 14 Dec 2025 15:40:45 +0200
Subject: [PATCH v1] Fix usage of palloc() in MERGE/SPLIT PARTITION(s) code
f2e4cc427951 and 4b3d173629f4 implement ALTER TABLE ... MERGE/SPLIT
PARTITION(s) commands. In several places, these commits use palloc(),
where we should use palloc_object() and palloc_array(). This commit
provides appropriate usage of palloc_object() and palloc_array().
Reported-by: Man Zeng <zengman@halodbtech.com>
Discussion: https://postgr.es/m/tencent_3661BB522D5466B33EA33666%40qq.com
---
src/backend/commands/tablecmds.c | 6 +++---
src/backend/partitioning/partbounds.c | 12 ++++--------
2 files changed, 7 insertions(+), 11 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 953fadb9c6b..7550ee7c164 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -22317,7 +22317,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
*/
if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED)
{
- newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
+ newval = palloc0_object(NewColumnValue);
newval->attnum = num;
newval->expr = expression_planner((Expr *) def);
newval->is_generated = (attribute->attgenerated != '\0');
@@ -22406,7 +22406,7 @@ createTableConstraints(List **wqueue, AlteredTableInfo *tab,
{
NewConstraint *newcon;
- newcon = (NewConstraint *) palloc0(sizeof(NewConstraint));
+ newcon = palloc0_object(NewConstraint);
newcon->name = ccon->name;
newcon->contype = CONSTR_CHECK;
newcon->qual = qual;
@@ -22944,7 +22944,7 @@ createSplitPartitionContext(Relation partRel)
{
SplitPartitionContext *pc;
- pc = (SplitPartitionContext *) palloc0(sizeof(SplitPartitionContext));
+ pc = palloc0_object(SplitPartitionContext);
pc->partRel = partRel;
/*
diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c
index b7f90ae109d..16b0adc172c 100644
--- a/src/backend/partitioning/partbounds.c
+++ b/src/backend/partitioning/partbounds.c
@@ -5115,8 +5115,7 @@ calculate_partition_bound_for_merge(Relation parent,
int nparts = list_length(partOids);
List *bounds = NIL;
- lower_bounds = (PartitionRangeBound **)
- palloc0(nparts * sizeof(PartitionRangeBound *));
+ lower_bounds = palloc0_array(PartitionRangeBound *, nparts);
/*
* Create an array of lower bounds and a list of
@@ -5755,8 +5754,7 @@ check_partitions_for_split(Relation parent,
* Make an array new_parts with new partitions except the DEFAULT
* partition.
*/
- new_parts = (SinglePartitionSpec **)
- palloc0(list_length(partlist) * sizeof(SinglePartitionSpec *));
+ new_parts = palloc0_array(SinglePartitionSpec *, list_length(partlist));
/* isSplitPartDefault flag: is split partition a DEFAULT partition? */
isSplitPartDefault = (defaultPartOid == splitPartOid);
@@ -5786,8 +5784,7 @@ check_partitions_for_split(Relation parent,
* all partitions in ascending order of their bounds (we compare the
* lower bound only).
*/
- lower_bounds = (PartitionRangeBound **)
- palloc0(nparts * sizeof(PartitionRangeBound *));
+ lower_bounds = palloc0_array(PartitionRangeBound *, nparts);
/* Create an array of lower bounds. */
for (i = 0; i < nparts; i++)
@@ -5802,8 +5799,7 @@ check_partitions_for_split(Relation parent,
/* Reorder the array of partitions. */
tmp_new_parts = new_parts;
- new_parts = (SinglePartitionSpec **)
- palloc0(nparts * sizeof(SinglePartitionSpec *));
+ new_parts = palloc0_array(SinglePartitionSpec *, nparts);
for (i = 0; i < nparts; i++)
new_parts[i] = tmp_new_parts[lower_bounds[i]->index];
--
2.39.5 (Apple Git-154)
Looks great! Thanks for your hard work – that’s all I’ve noticed for now.
Regards,
Man Zeng
On Sun, Dec 14, 2025 at 4:06 PM zengman <zengman@halodbtech.com> wrote:
Looks great! Thanks for your hard work – that’s all I’ve noticed for now.
Pushed, thank you!
------
Regards,
Alexander Korotkov
Supabase
Hi Alexander,
I found this feature merged; thanks for this work.
I tested it and found that one place in the error errcode may need to be
changed.
In checkPartition():
...
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
...
ERRCODE_UNDEFINED_TABLE usually means "table does not exist."
When entering here, the table should exist, otherwise table_open() already
reports an error.
I found another two errcode in checkPartition()
use ERRCODE_WRONG_OBJECT_TYPE,
In the attached patch, I replace ERRCODE_UNDEFINED_TABLE with
ERRCODE_WRONG_OBJECT_TYPE.
--
Thanks,
Tender Wang
Attachments:
0001-Adjust-errcode-in-checkPartition.patchapplication/octet-stream; name=0001-Adjust-errcode-in-checkPartition.patchDownload
From 676cde81fda01233ef707761334d6d59c906efe2 Mon Sep 17 00:00:00 2001
From: Tender Wang <tndrwang@gmail.com>
Date: Sat, 20 Dec 2025 10:56:36 +0800
Subject: [PATCH] Adjust errcode in checkPartition().
Replace ERRCODE_UNDEFINED_TABLE with ERRCODE_WRONG_OBJECT_TYPE.
---
src/backend/parser/parse_utilcmd.c | 2 +-
1 file changed, 1 insertion(+), 1 deletion(-)
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 2b7b084f216..3abe5410b4c 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3544,7 +3544,7 @@ checkPartition(Relation rel, Oid partRelOid, bool isMerge)
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
- errcode(ERRCODE_UNDEFINED_TABLE),
+ errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
isMerge
--
2.34.1
hi!
I have been looking though git log, noticed this commit, and did small tests.
This is what I found:
```
reshke=# create table z(i int) partition by range(i);
CREATE TABLE
reshke=# create table z_1 partition of z for values from (0)to(1);
CREATE TABLE
reshke=# create table z_2 partition of z for values from (1)to(2);
CREATE TABLE
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
ALTER TABLE
reshke=#
```
IMO "alter table only ... merge partitions" does not make perfect
sense and should be rejected rather than executed. WDYT?
Hi Kirill!
On Sat, Dec 20, 2025 at 10:58 AM Kirill Reshke <reshkekirill@gmail.com> wrote:
I have been looking though git log, noticed this commit, and did small tests.
This is what I found:
```
reshke=# create table z(i int) partition by range(i);
CREATE TABLE
reshke=# create table z_1 partition of z for values from (0)to(1);
CREATE TABLE
reshke=# create table z_2 partition of z for values from (1)to(2);
CREATE TABLE
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
ALTER TABLE
reshke=#```
IMO "alter table only ... merge partitions" does not make perfect
sense and should be rejected rather than executed. WDYT?
Could you, please, clarify your point? I didn't quite get it. It
looks like pretty basic example of merging two adjacent partitions.
------
Regards,
Alexander Korotkov
Supabase
Hi Tender,
On Sat, Dec 20, 2025 at 5:18 AM Tender Wang <tndrwang@gmail.com> wrote:
I found this feature merged; thanks for this work.
I tested it and found that one place in the error errcode may need to be changed.
In checkPartition():
...
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
...ERRCODE_UNDEFINED_TABLE usually means "table does not exist."
When entering here, the table should exist, otherwise table_open() already reports an error.
I found another two errcode in checkPartition() use ERRCODE_WRONG_OBJECT_TYPE,
In the attached patch, I replace ERRCODE_UNDEFINED_TABLE with ERRCODE_WRONG_OBJECT_TYPE.
I agree with you that ERRCODE_UNDEFINED_TABLE is certainly wrong error
code because the table actually exists. ERRCODE_WRONG_OBJECT_TYPE is
better. For example, we throw it when trying to attach a partition to
non-partitioned table. So, the parent table type is wrong. However,
are objects in the situation under consideration really have wrong
type? The problem is that one table is not partition of another.
However, it's possibly that they could be attached without changing of
their types. So, I think about
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE. What do you think?
------
Regards,
Alexander Korotkov
Supabase
On Sat, Dec 20, 2025 at 6:42 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
Hi Kirill!
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
ALTER TABLE
reshke=#```
IMO "alter table only ... merge partitions" does not make perfect
sense and should be rejected rather than executed. WDYT?Could you, please, clarify your point? I didn't quite get it. It
looks like pretty basic example of merging two adjacent partitions.
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
I think it should fail, because we are not applying to table "z" itself,
For Split/Merge partitions, we are processing the whole partitioned
table z hierarchy.
alter table z merge partitions (z_1,z_2) into z_12;
should work.
I guess the attached maybe is what Krill wants.
Attachments:
v1-0001-disallow-ALTER-TABLE-ONLY-in-MERGE-SPLIT-PARTITIONS.patchapplication/x-patch; name=v1-0001-disallow-ALTER-TABLE-ONLY-in-MERGE-SPLIT-PARTITIONS.patchDownload
From 4ddd54a1516b8e72aaede2b9722f457967ac7f0c Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Sat, 20 Dec 2025 19:03:47 +0800
Subject: [PATCH v1 1/1] disallow ALTER TABLE ONLY in MERGE SPLIT PARTITIONS
dicussion: : https://postgr.es/m/CALdSSPj6ixZC2EaTgJU_2BNhgjsg_8665x2-pDzcEoc-PRueAA@mail.gmail.com
---
src/backend/commands/tablecmds.c | 7 +++++--
src/backend/parser/parse_utilcmd.c | 12 ++++++++++++
src/test/regress/expected/partition_merge.out | 4 ++++
src/test/regress/expected/partition_split.out | 6 ++++++
src/test/regress/sql/partition_merge.sql | 4 ++++
src/test/regress/sql/partition_split.sql | 5 +++++
6 files changed, 36 insertions(+), 2 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 6b1a00ed477..e3da673c417 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -5283,6 +5283,9 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
break;
case AT_MergePartitions:
case AT_SplitPartition:
+ /* Set up recursion for phase 2; no other prep needed */
+ if (recurse)
+ cmd->recurse = true;
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5684,7 +5687,7 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
case AT_MergePartitions:
- cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, cmd->recurse, lockmode,
cur_pass, context);
Assert(cmd != NULL);
Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
@@ -5692,7 +5695,7 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
context);
break;
case AT_SplitPartition:
- cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, cmd->recurse, lockmode,
cur_pass, context);
Assert(cmd != NULL);
Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 2b7b084f216..2d0d28d6ddb 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -4080,6 +4080,12 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of partitions to be merged should include at least two partitions"));
+ if (!cxt.relation->inh)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_TABLE_DEFINITION),
+ errmsg("%s must apply to child tables too", "ALTER TABLE MERGE PARTITIONS"),
+ errhint("Do not specify the ONLY keyword."));
+
transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
@@ -4094,6 +4100,12 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two partitions"));
+ if (!cxt.relation->inh)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_TABLE_DEFINITION),
+ errmsg("%s must apply to child tables too", "ALTER TABLE SPLIT PARTITIONS"),
+ errhint("Do not specify the ONLY keyword."));
+
transformPartitionCmdForSplit(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 3e40abf38a0..e5b30adeb30 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -21,6 +21,10 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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, can not specify ONLY
+ALTER TABLE ONLY sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022) INTO sales_feb_mar_apr2022;
+ERROR: ALTER TABLE MERGE PARTITIONS must apply to child tables too
+HINT: Do not specify the ONLY keyword.
-- ERROR: partition with name "sales_feb2022" is 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" is already used
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index e68baf71daf..766ab7c988a 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -15,6 +15,12 @@ CREATE TABLE sales_range (salesperson_id int, sales_date date) PARTITION BY RANG
CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range SPLIT PARTITION sales_jan2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'));
+ERROR: ALTER TABLE SPLIT PARTITIONS must apply to child tables too
+HINT: Do not specify the ONLY keyword.
-- ERROR: relation "sales_xxx" does not exist
ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index ffb498612a6..c219130a0d8 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -27,8 +27,12 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022) INTO sales_feb_mar_apr2022;
+
-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
+
-- ERROR: "sales_apr2022" is not a table
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022;
-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022"
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 0e79c036ea9..36714a3a892 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -19,6 +19,11 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range SPLIT PARTITION sales_jan2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'));
+
-- ERROR: relation "sales_xxx" does not exist
ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
--
2.39.5 (Apple Git-154)
v1-0001-disallow-ALTER-TABLE-ONLY-in-MERGE-SPLIT-PARTITIONS.patchapplication/x-patch; name=v1-0001-disallow-ALTER-TABLE-ONLY-in-MERGE-SPLIT-PARTITIONS.patchDownload
From 5f52cc7cdad88f5d0e6677548e27e4354ef3c532 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Sat, 20 Dec 2025 19:12:58 +0800
Subject: [PATCH v1 1/1] disallow ALTER TABLE ONLY in MERGE SPLIT PARTITIONS
dicussion: : https://postgr.es/m/CALdSSPj6ixZC2EaTgJU_2BNhgjsg_8665x2-pDzcEoc-PRueAA@mail.gmail.com
---
src/backend/commands/tablecmds.c | 7 +++++--
src/backend/parser/parse_utilcmd.c | 12 ++++++++++++
src/test/regress/expected/partition_merge.out | 4 ++++
src/test/regress/expected/partition_split.out | 6 ++++++
src/test/regress/sql/partition_merge.sql | 3 +++
src/test/regress/sql/partition_split.sql | 5 +++++
6 files changed, 35 insertions(+), 2 deletions(-)
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 6b1a00ed477..e3da673c417 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -5283,6 +5283,9 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd,
break;
case AT_MergePartitions:
case AT_SplitPartition:
+ /* Set up recursion for phase 2; no other prep needed */
+ if (recurse)
+ cmd->recurse = true;
ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
@@ -5684,7 +5687,7 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name);
break;
case AT_MergePartitions:
- cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, cmd->recurse, lockmode,
cur_pass, context);
Assert(cmd != NULL);
Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
@@ -5692,7 +5695,7 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab,
context);
break;
case AT_SplitPartition:
- cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode,
+ cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, cmd->recurse, lockmode,
cur_pass, context);
Assert(cmd != NULL);
Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE);
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 2b7b084f216..2d0d28d6ddb 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -4080,6 +4080,12 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of partitions to be merged should include at least two partitions"));
+ if (!cxt.relation->inh)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_TABLE_DEFINITION),
+ errmsg("%s must apply to child tables too", "ALTER TABLE MERGE PARTITIONS"),
+ errhint("Do not specify the ONLY keyword."));
+
transformPartitionCmdForMerge(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
@@ -4094,6 +4100,12 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt,
errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("list of new partitions should contain at least two partitions"));
+ if (!cxt.relation->inh)
+ ereport(ERROR,
+ errcode(ERRCODE_INVALID_TABLE_DEFINITION),
+ errmsg("%s must apply to child tables too", "ALTER TABLE SPLIT PARTITIONS"),
+ errhint("Do not specify the ONLY keyword."));
+
transformPartitionCmdForSplit(&cxt, partcmd);
newcmds = lappend(newcmds, cmd);
break;
diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out
index 3e40abf38a0..e5b30adeb30 100644
--- a/src/test/regress/expected/partition_merge.out
+++ b/src/test/regress/expected/partition_merge.out
@@ -21,6 +21,10 @@ CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01
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, can not specify ONLY
+ALTER TABLE ONLY sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022) INTO sales_feb_mar_apr2022;
+ERROR: ALTER TABLE MERGE PARTITIONS must apply to child tables too
+HINT: Do not specify the ONLY keyword.
-- ERROR: partition with name "sales_feb2022" is 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" is already used
diff --git a/src/test/regress/expected/partition_split.out b/src/test/regress/expected/partition_split.out
index e68baf71daf..766ab7c988a 100644
--- a/src/test/regress/expected/partition_split.out
+++ b/src/test/regress/expected/partition_split.out
@@ -15,6 +15,12 @@ CREATE TABLE sales_range (salesperson_id int, sales_date date) PARTITION BY RANG
CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01');
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range SPLIT PARTITION sales_jan2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'));
+ERROR: ALTER TABLE SPLIT PARTITIONS must apply to child tables too
+HINT: Do not specify the ONLY keyword.
-- ERROR: relation "sales_xxx" does not exist
ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql
index ffb498612a6..a51ae1b090f 100644
--- a/src/test/regress/sql/partition_merge.sql
+++ b/src/test/regress/sql/partition_merge.sql
@@ -27,6 +27,9 @@ ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022) INTO sales_feb_mar_apr2022;
+
-- ERROR: partition with name "sales_feb2022" is already used
ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022;
-- ERROR: "sales_apr2022" is not a table
diff --git a/src/test/regress/sql/partition_split.sql b/src/test/regress/sql/partition_split.sql
index 0e79c036ea9..36714a3a892 100644
--- a/src/test/regress/sql/partition_split.sql
+++ b/src/test/regress/sql/partition_split.sql
@@ -19,6 +19,11 @@ CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01
CREATE TABLE sales_feb_mar_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-05-01');
CREATE TABLE sales_others PARTITION OF sales_range DEFAULT;
+-- ERROR, can not specify ONLY
+ALTER TABLE ONLY sales_range SPLIT PARTITION sales_jan2022 INTO
+ (PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
+ PARTITION sales_mar2022 FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'));
+
-- ERROR: relation "sales_xxx" does not exist
ALTER TABLE sales_range SPLIT PARTITION sales_xxx INTO
(PARTITION sales_feb2022 FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'),
--
2.39.5 (Apple Git-154)
On Sat, Dec 20, 2025 at 1:15 PM jian he <jian.universality@gmail.com> wrote:
On Sat, Dec 20, 2025 at 6:42 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
Hi Kirill!
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
ALTER TABLE
reshke=#```
IMO "alter table only ... merge partitions" does not make perfect
sense and should be rejected rather than executed. WDYT?Could you, please, clarify your point? I didn't quite get it. It
looks like pretty basic example of merging two adjacent partitions.reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
I think it should fail, because we are not applying to table "z" itself,
For Split/Merge partitions, we are processing the whole partitioned
table z hierarchy.alter table z merge partitions (z_1,z_2) into z_12;
should work.I guess the attached maybe is what Krill wants.
Thank you. I missed there is an ONLY keyword. But I'm not sure about
the error message. I don't think the problem with ONLY keyword is
that MERGE/SPLIT must be always recursive. I think opposite, it's
always non-recursive and this is why ONLY is meaningless. Otherwise,
we may decide to just leave it as it allowing ONLY.
------
Regards,
Alexander Korotkov
Supabase
On Sat, 20 Dec 2025 at 16:27, Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Sat, Dec 20, 2025 at 1:15 PM jian he <jian.universality@gmail.com> wrote:
On Sat, Dec 20, 2025 at 6:42 PM Alexander Korotkov <aekorotkov@gmail.com> wrote:
Hi Kirill!
reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
ALTER TABLE
reshke=#```
IMO "alter table only ... merge partitions" does not make perfect
sense and should be rejected rather than executed. WDYT?Could you, please, clarify your point? I didn't quite get it. It
looks like pretty basic example of merging two adjacent partitions.reshke=# alter table only z merge partitions (z_1,z_2) into z_12;
I think it should fail, because we are not applying to table "z" itself,
For Split/Merge partitions, we are processing the whole partitioned
table z hierarchy.alter table z merge partitions (z_1,z_2) into z_12;
should work.I guess the attached maybe is what Krill wants.
Jian, Thank, you got me right. Your patch is addressing the problem I
talk about, yes. The only issue about your patch is the actual error
message (error hint is exactly on point.)
So, instead of
```
+ERROR: ALTER TABLE MERGE PARTITIONS must apply to child tables too
+HINT: Do not specify the ONLY keyword.
``
I would prefer (something like)
```
+ERROR: ALTER TABLE MERGE PARTITIONS is a non-recursive command.
+HINT: Do not specify the ONLY keyword.
``
On Sat, 20 Dec 2025 at 16:27, Alexander Korotkov <aekorotkov@gmail.com> wrote:
I don't think the problem with ONLY keyword is
that MERGE/SPLIT must be always recursive. I think opposite, it's
always non-recursive and this is why ONLY is meaningless. Otherwise,
we may decide to just leave it as it allowing ONLY.
+1
--
Best regards,
Kirill Reshke
Alexander Korotkov <aekorotkov@gmail.com> 于2025年12月20日周六 19:08写道:
Hi Tender,
On Sat, Dec 20, 2025 at 5:18 AM Tender Wang <tndrwang@gmail.com> wrote:
I found this feature merged; thanks for this work.
I tested it and found that one place in the error errcode may need to bechanged.
In checkPartition():
...
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
...ERRCODE_UNDEFINED_TABLE usually means "table does not exist."
When entering here, the table should exist, otherwise table_open()already reports an error.
I found another two errcode in checkPartition() use
ERRCODE_WRONG_OBJECT_TYPE,
In the attached patch, I replace ERRCODE_UNDEFINED_TABLE with
ERRCODE_WRONG_OBJECT_TYPE.
I agree with you that ERRCODE_UNDEFINED_TABLE is certainly wrong error
code because the table actually exists. ERRCODE_WRONG_OBJECT_TYPE is
better. For example, we throw it when trying to attach a partition to
non-partitioned table. So, the parent table type is wrong. However,
are objects in the situation under consideration really have wrong
type? The problem is that one table is not partition of another.
However, it's possibly that they could be attached without changing of
their types. So, I think about
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE. What do you think?
It's ok for me. Please check the v2 patch.
--
Thanks,
Tender Wang
Attachments:
v2-0001-Adjust-errcode-in-checkPartition.patchtext/plain; charset=US-ASCII; name=v2-0001-Adjust-errcode-in-checkPartition.patchDownload
From 492c595cf481c67eb2b4823ae3e389d0a6fb7f83 Mon Sep 17 00:00:00 2001
From: Tender Wang <tndrwang@gmail.com>
Date: Sat, 20 Dec 2025 10:56:36 +0800
Subject: [PATCH v2] Adjust errcode in checkPartition().
Replace ERRCODE_UNDEFINED_TABLE with ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE.
---
src/backend/parser/parse_utilcmd.c | 2 +-
1 file changed, 1 insertion(+), 1 deletion(-)
diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c
index 2b7b084f216..de8c0a5560b 100644
--- a/src/backend/parser/parse_utilcmd.c
+++ b/src/backend/parser/parse_utilcmd.c
@@ -3544,7 +3544,7 @@ checkPartition(Relation rel, Oid partRelOid, bool isMerge)
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
- errcode(ERRCODE_UNDEFINED_TABLE),
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
RelationGetRelationName(partRel), RelationGetRelationName(rel)),
isMerge
--
2.34.1
On Sun, 21 Dec 2025, 12:14 Tender Wang, <tndrwang@gmail.com> wrote:
Alexander Korotkov <aekorotkov@gmail.com> 于2025年12月20日周六 19:08写道:
Hi Tender,
On Sat, Dec 20, 2025 at 5:18 AM Tender Wang <tndrwang@gmail.com> wrote:
I found this feature merged; thanks for this work.
I tested it and found that one place in the error errcode may need tobe changed.
In checkPartition():
...
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
...ERRCODE_UNDEFINED_TABLE usually means "table does not exist."
When entering here, the table should exist, otherwise table_open()already reports an error.
I found another two errcode in checkPartition() use
ERRCODE_WRONG_OBJECT_TYPE,
In the attached patch, I replace ERRCODE_UNDEFINED_TABLE with
ERRCODE_WRONG_OBJECT_TYPE.
I agree with you that ERRCODE_UNDEFINED_TABLE is certainly wrong error
code because the table actually exists. ERRCODE_WRONG_OBJECT_TYPE is
better. For example, we throw it when trying to attach a partition to
non-partitioned table. So, the parent table type is wrong. However,
are objects in the situation under consideration really have wrong
type? The problem is that one table is not partition of another.
However, it's possibly that they could be attached without changing of
their types. So, I think about
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE. What do you think?It's ok for me. Please check the v2 patch.
--
Thanks,
Tender Wang
On Sun, 21 Dec 2025, 12:14 Tender Wang, <tndrwang@gmail.com> wrote:
Alexander Korotkov <aekorotkov@gmail.com> 于2025年12月20日周六 19:08写道:
Hi Tender,
On Sat, Dec 20, 2025 at 5:18 AM Tender Wang <tndrwang@gmail.com> wrote:
I found this feature merged; thanks for this work.
I tested it and found that one place in the error errcode may need tobe changed.
In checkPartition():
...
if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel))
ereport(ERROR,
errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" is not a partition of relation \"%s\"",
...ERRCODE_UNDEFINED_TABLE usually means "table does not exist."
When entering here, the table should exist, otherwise table_open()already reports an error.
I found another two errcode in checkPartition() use
ERRCODE_WRONG_OBJECT_TYPE,
In the attached patch, I replace ERRCODE_UNDEFINED_TABLE with
ERRCODE_WRONG_OBJECT_TYPE.
I agree with you that ERRCODE_UNDEFINED_TABLE is certainly wrong error
code because the table actually exists. ERRCODE_WRONG_OBJECT_TYPE is
better. For example, we throw it when trying to attach a partition to
non-partitioned table. So, the parent table type is wrong. However,
are objects in the situation under consideration really have wrong
type? The problem is that one table is not partition of another.
However, it's possibly that they could be attached without changing of
their types. So, I think about
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE. What do you think?It's ok for me. Please check the v2 patch.
--
Thanks,
Tender Wang
Hi! Your v2 looks fine
The only question for me is, should we add any regression test to exercise
this code, or it is not worth the troubles?
Show quoted text
On Sun, Dec 21, 2025 at 9:42 AM Kirill Reshke <reshkekirill@gmail.com> wrote:
On Sun, 21 Dec 2025, 12:14 Tender Wang, <tndrwang@gmail.com> wrote:
Alexander Korotkov <aekorotkov@gmail.com> 于2025年12月20日周六 19:08写道:
I agree with you that ERRCODE_UNDEFINED_TABLE is certainly wrong error
code because the table actually exists. ERRCODE_WRONG_OBJECT_TYPE is
better. For example, we throw it when trying to attach a partition to
non-partitioned table. So, the parent table type is wrong. However,
are objects in the situation under consideration really have wrong
type? The problem is that one table is not partition of another.
However, it's possibly that they could be attached without changing of
their types. So, I think about
ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE. What do you think?It's ok for me. Please check the v2 patch.
Hi! Your v2 looks fine
The only question for me is, should we add any regression test to exercise this code, or it is not worth the troubles?
I've checked contents of out regression tests. I see we very rarely
include SQLSTATE there, mostly in psql and plpgsql tests. Thus, I
think we should just fix the SQLSTATE without dedicating a test for
that. So, I'm going to push the patch from Tender Wang if no
objections.
------
Regards,
Alexander Korotkov
Supabase
On Mon, 22 Dec 2025 at 03:02, Alexander Korotkov <aekorotkov@gmail.com> wrote:
On Sun, Dec 21, 2025 at 9:42 AM Kirill Reshke <reshkekirill@gmail.com> wrote:
Hi! Your v2 looks fine
The only question for me is, should we add any regression test to exercise this code, or it is not worth the troubles?I've checked contents of out regression tests. I see we very rarely
include SQLSTATE there, mostly in psql and plpgsql tests. Thus, I
think we should just fix the SQLSTATE without dedicating a test for
that. So, I'm going to push the patch from Tender Wang if no
objections.
Ok, no objections.
--
Best regards,
Kirill Reshke
Hi,
Kirill Reshke <reshkekirill@gmail.com> 于2025年12月22日周一 13:47写道:
On Mon, 22 Dec 2025 at 03:02, Alexander Korotkov <aekorotkov@gmail.com>
wrote:On Sun, Dec 21, 2025 at 9:42 AM Kirill Reshke <reshkekirill@gmail.com>
wrote:
Hi! Your v2 looks fine
The only question for me is, should we add any regression test toexercise this code, or it is not worth the troubles?
I've checked contents of out regression tests. I see we very rarely
include SQLSTATE there, mostly in psql and plpgsql tests. Thus, I
think we should just fix the SQLSTATE without dedicating a test for
that. So, I'm going to push the patch from Tender Wang if no
objections.Ok, no objections.
I added this to [1]https://commitfest.postgresql.org/patch/6376/ -- Thanks, Tender Wang commitfest in case we forgot this little issue.
[1]: https://commitfest.postgresql.org/patch/6376/ -- Thanks, Tender Wang
--
Thanks,
Tender Wang
On 2026-Jan-05, Tender Wang wrote:
I added this to [1] commitfest in case we forgot this little issue.
The commitfest is not the right place for this kind of item. The Open
Items wiki page is. This ensures that this problem will be fixed in
later cycles of the development process, before the next major release.
https://wiki.postgresql.org/wiki/PostgreSQL_19_Open_Items
Thanks
--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
"Las mujeres son como hondas: mientras más resistencia tienen,
más lejos puedes llegar con ellas" (Jonas Nightingale, Leap of Faith)
Hi,
Álvaro Herrera <alvherre@kurilemu.de> 于2026年1月6日周二 14:39写道:
On 2026-Jan-05, Tender Wang wrote:
I added this to [1] commitfest in case we forgot this little issue.
The commitfest is not the right place for this kind of item. The Open
Items wiki page is. This ensures that this problem will be fixed in
later cycles of the development process, before the next major release.
https://wiki.postgresql.org/wiki/PostgreSQL_19_Open_Items
Thanks for this information.
Since Alexander has committed, no need to add it to the 19 open items wiki.
And I closed the item in the commitfest.
--
Thanks,
Tender Wang